Add user_last_timestamp column to user_newtalk table
[lhc/web/wiklou.git] / maintenance / postgres / tables.sql
1 -- SQL to create the initial tables for the MediaWiki database.
2 -- This is read and executed by the install script; you should
3 -- not have to run it by itself unless doing a manual install.
4 -- This is the PostgreSQL version.
5 -- For information about each table, please see the notes in maintenance/tables.sql
6 -- Please make sure all dollar-quoting uses $mw$ at the start of the line
7 -- TODO: Change CHAR/SMALLINT to BOOL (still used in a non-bool fashion in PHP code)
8
9 BEGIN;
10 SET client_min_messages = 'ERROR';
11
12 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
13 CREATE TABLE mwuser ( -- replace reserved word 'user'
14 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
15 user_name TEXT NOT NULL UNIQUE,
16 user_real_name TEXT,
17 user_password TEXT,
18 user_newpassword TEXT,
19 user_newpass_time TIMESTAMPTZ,
20 user_token TEXT,
21 user_email TEXT,
22 user_email_token TEXT,
23 user_email_token_expires TIMESTAMPTZ,
24 user_email_authenticated TIMESTAMPTZ,
25 user_options TEXT,
26 user_touched TIMESTAMPTZ,
27 user_registration TIMESTAMPTZ,
28 user_editcount INTEGER
29 );
30 CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
31
32 -- Create a dummy user to satisfy fk contraints especially with revisions
33 INSERT INTO mwuser
34 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
35
36 CREATE TABLE user_groups (
37 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
38 ug_group TEXT NOT NULL
39 );
40 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
41
42 CREATE TABLE user_newtalk (
43 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
44 user_ip TEXT NULL,
45 user_last_timestamp TIMESTAMPTZ
46 );
47 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
48 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
49
50
51 CREATE SEQUENCE page_page_id_seq;
52 CREATE TABLE page (
53 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
54 page_namespace SMALLINT NOT NULL,
55 page_title TEXT NOT NULL,
56 page_restrictions TEXT,
57 page_counter BIGINT NOT NULL DEFAULT 0,
58 page_is_redirect SMALLINT NOT NULL DEFAULT 0,
59 page_is_new SMALLINT NOT NULL DEFAULT 0,
60 page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(),
61 page_touched TIMESTAMPTZ,
62 page_latest INTEGER NOT NULL, -- FK?
63 page_len INTEGER NOT NULL
64 );
65 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
66 CREATE INDEX page_main_title ON page (page_title) WHERE page_namespace = 0;
67 CREATE INDEX page_talk_title ON page (page_title) WHERE page_namespace = 1;
68 CREATE INDEX page_user_title ON page (page_title) WHERE page_namespace = 2;
69 CREATE INDEX page_utalk_title ON page (page_title) WHERE page_namespace = 3;
70 CREATE INDEX page_project_title ON page (page_title) WHERE page_namespace = 4;
71 CREATE INDEX page_random_idx ON page (page_random);
72 CREATE INDEX page_len_idx ON page (page_len);
73
74 CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS
75 $mw$
76 BEGIN
77 DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title;
78 RETURN NULL;
79 END;
80 $mw$;
81
82 CREATE TRIGGER page_deleted AFTER DELETE ON page
83 FOR EACH ROW EXECUTE PROCEDURE page_deleted();
84
85 CREATE SEQUENCE rev_rev_id_val;
86 CREATE TABLE revision (
87 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('rev_rev_id_val'),
88 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
89 rev_text_id INTEGER NULL, -- FK
90 rev_comment TEXT,
91 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT,
92 rev_user_text TEXT NOT NULL,
93 rev_timestamp TIMESTAMPTZ NOT NULL,
94 rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
95 rev_deleted SMALLINT NOT NULL DEFAULT 0,
96 rev_len INTEGER NULL,
97 rev_parent_id INTEGER NULL
98 );
99 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
100 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
101 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
102 CREATE INDEX rev_user_idx ON revision (rev_user);
103 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
104
105
106 CREATE SEQUENCE text_old_id_val;
107 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
108 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_val'),
109 old_text TEXT,
110 old_flags TEXT
111 );
112
113
114 CREATE SEQUENCE pr_id_val;
115 CREATE TABLE page_restrictions (
116 pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('pr_id_val'),
117 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
118 pr_type TEXT NOT NULL,
119 pr_level TEXT NOT NULL,
120 pr_cascade SMALLINT NOT NULL,
121 pr_user INTEGER NULL,
122 pr_expiry TIMESTAMPTZ NULL
123 );
124 ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
125
126 CREATE TABLE page_props (
127 pp_page INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
128 pp_propname TEXT NOT NULL,
129 pp_value TEXT NOT NULL
130 );
131 ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
132 CREATE INDEX page_props_propname ON page_props (pp_propname);
133
134 CREATE TABLE archive (
135 ar_namespace SMALLINT NOT NULL,
136 ar_title TEXT NOT NULL,
137 ar_text TEXT, -- technically should be bytea, but not used anymore
138 ar_page_id INTEGER NULL,
139 ar_parent_id INTEGER NULL,
140 ar_comment TEXT,
141 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
142 ar_user_text TEXT NOT NULL,
143 ar_timestamp TIMESTAMPTZ NOT NULL,
144 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
145 ar_flags TEXT,
146 ar_rev_id INTEGER,
147 ar_text_id INTEGER,
148 ar_deleted SMALLINT NOT NULL DEFAULT 0,
149 ar_len INTEGER NULL
150 );
151 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
152 CREATE INDEX archive_user_text ON archive (ar_user_text);
153
154
155 CREATE TABLE redirect (
156 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
157 rd_namespace SMALLINT NOT NULL,
158 rd_title TEXT NOT NULL
159 );
160 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
161
162
163 CREATE TABLE pagelinks (
164 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
165 pl_namespace SMALLINT NOT NULL,
166 pl_title TEXT NOT NULL
167 );
168 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
169
170 CREATE TABLE templatelinks (
171 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
172 tl_namespace SMALLINT NOT NULL,
173 tl_title TEXT NOT NULL
174 );
175 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
176
177 CREATE TABLE imagelinks (
178 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
179 il_to TEXT NOT NULL
180 );
181 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
182
183 CREATE TABLE categorylinks (
184 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
185 cl_to TEXT NOT NULL,
186 cl_sortkey TEXT,
187 cl_timestamp TIMESTAMPTZ NOT NULL
188 );
189 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
190 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
191
192 CREATE TABLE externallinks (
193 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
194 el_to TEXT NOT NULL,
195 el_index TEXT NOT NULL
196 );
197 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
198 CREATE INDEX externallinks_index ON externallinks (el_index);
199
200 CREATE TABLE langlinks (
201 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
202 ll_lang TEXT,
203 ll_title TEXT
204 );
205 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
206 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
207
208
209 CREATE TABLE site_stats (
210 ss_row_id INTEGER NOT NULL UNIQUE,
211 ss_total_views INTEGER DEFAULT 0,
212 ss_total_edits INTEGER DEFAULT 0,
213 ss_good_articles INTEGER DEFAULT 0,
214 ss_total_pages INTEGER DEFAULT -1,
215 ss_users INTEGER DEFAULT -1,
216 ss_admins INTEGER DEFAULT -1,
217 ss_images INTEGER DEFAULT 0
218 );
219
220 CREATE TABLE hitcounter (
221 hc_id BIGINT NOT NULL
222 );
223
224
225 CREATE SEQUENCE ipblocks_ipb_id_val;
226 CREATE TABLE ipblocks (
227 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
228 ipb_address TEXT NULL,
229 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
230 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
231 ipb_by_text TEXT NOT NULL DEFAULT '',
232 ipb_reason TEXT NOT NULL,
233 ipb_timestamp TIMESTAMPTZ NOT NULL,
234 ipb_auto SMALLINT NOT NULL DEFAULT 0,
235 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
236 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
237 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
238 ipb_expiry TIMESTAMPTZ NOT NULL,
239 ipb_range_start TEXT,
240 ipb_range_end TEXT,
241 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
242 ipb_block_email SMALLINT NOT NULL DEFAULT 0
243
244 );
245 CREATE INDEX ipb_address ON ipblocks (ipb_address);
246 CREATE INDEX ipb_user ON ipblocks (ipb_user);
247 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
248
249
250 CREATE TABLE image (
251 img_name TEXT NOT NULL PRIMARY KEY,
252 img_size INTEGER NOT NULL,
253 img_width INTEGER NOT NULL,
254 img_height INTEGER NOT NULL,
255 img_metadata BYTEA NOT NULL DEFAULT '',
256 img_bits SMALLINT,
257 img_media_type TEXT,
258 img_major_mime TEXT DEFAULT 'unknown',
259 img_minor_mime TEXT DEFAULT 'unknown',
260 img_description TEXT NOT NULL,
261 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
262 img_user_text TEXT NOT NULL,
263 img_timestamp TIMESTAMPTZ,
264 img_sha1 TEXT NOT NULL DEFAULT ''
265 );
266 CREATE INDEX img_size_idx ON image (img_size);
267 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
268 CREATE INDEX img_sha1 ON image (img_sha1);
269
270 CREATE TABLE oldimage (
271 oi_name TEXT NOT NULL,
272 oi_archive_name TEXT NOT NULL,
273 oi_size INTEGER NOT NULL,
274 oi_width INTEGER NOT NULL,
275 oi_height INTEGER NOT NULL,
276 oi_bits SMALLINT NOT NULL,
277 oi_description TEXT,
278 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
279 oi_user_text TEXT NOT NULL,
280 oi_timestamp TIMESTAMPTZ NOT NULL,
281 oi_metadata BYTEA NOT NULL DEFAULT '',
282 oi_media_type TEXT NULL,
283 oi_major_mime TEXT NOT NULL DEFAULT 'unknown',
284 oi_minor_mime TEXT NOT NULL DEFAULT 'unknown',
285 oi_deleted SMALLINT NOT NULL DEFAULT 0,
286 oi_sha1 TEXT NOT NULL DEFAULT ''
287 );
288 ALTER TABLE oldimage ADD CONSTRAINT oldimage_oi_name_fkey_cascade FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE;
289 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
290 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
291 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
292
293
294 CREATE SEQUENCE filearchive_fa_id_seq;
295 CREATE TABLE filearchive (
296 fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
297 fa_name TEXT NOT NULL,
298 fa_archive_name TEXT,
299 fa_storage_group TEXT,
300 fa_storage_key TEXT,
301 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
302 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
303 fa_deleted_reason TEXT,
304 fa_size INTEGER NOT NULL,
305 fa_width INTEGER NOT NULL,
306 fa_height INTEGER NOT NULL,
307 fa_metadata BYTEA NOT NULL DEFAULT '',
308 fa_bits SMALLINT,
309 fa_media_type TEXT,
310 fa_major_mime TEXT DEFAULT 'unknown',
311 fa_minor_mime TEXT DEFAULT 'unknown',
312 fa_description TEXT NOT NULL,
313 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
314 fa_user_text TEXT NOT NULL,
315 fa_timestamp TIMESTAMPTZ,
316 fa_deleted SMALLINT NOT NULL DEFAULT 0
317 );
318 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
319 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
320 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
321 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
322
323
324 CREATE SEQUENCE rc_rc_id_seq;
325 CREATE TABLE recentchanges (
326 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
327 rc_timestamp TIMESTAMPTZ NOT NULL,
328 rc_cur_time TIMESTAMPTZ NOT NULL,
329 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
330 rc_user_text TEXT NOT NULL,
331 rc_namespace SMALLINT NOT NULL,
332 rc_title TEXT NOT NULL,
333 rc_comment TEXT,
334 rc_minor SMALLINT NOT NULL DEFAULT 0,
335 rc_bot SMALLINT NOT NULL DEFAULT 0,
336 rc_new SMALLINT NOT NULL DEFAULT 0,
337 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
338 rc_this_oldid INTEGER NOT NULL,
339 rc_last_oldid INTEGER NOT NULL,
340 rc_type SMALLINT NOT NULL DEFAULT 0,
341 rc_moved_to_ns SMALLINT,
342 rc_moved_to_title TEXT,
343 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
344 rc_ip CIDR,
345 rc_old_len INTEGER,
346 rc_new_len INTEGER,
347 rc_deleted SMALLINT NOT NULL DEFAULT 0,
348 rc_logid INTEGER NOT NULL DEFAULT 0,
349 rc_log_type TEXT,
350 rc_log_action TEXT,
351 rc_params TEXT
352 );
353 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
354 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
355 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
356 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
357 CREATE INDEX rc_ip ON recentchanges (rc_ip);
358
359
360 CREATE TABLE watchlist (
361 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
362 wl_namespace SMALLINT NOT NULL DEFAULT 0,
363 wl_title TEXT NOT NULL,
364 wl_notificationtimestamp TIMESTAMPTZ
365 );
366 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
367
368
369 CREATE TABLE math (
370 math_inputhash BYTEA NOT NULL UNIQUE,
371 math_outputhash BYTEA NOT NULL,
372 math_html_conservativeness SMALLINT NOT NULL,
373 math_html TEXT,
374 math_mathml TEXT
375 );
376
377
378 CREATE TABLE interwiki (
379 iw_prefix TEXT NOT NULL UNIQUE,
380 iw_url TEXT NOT NULL,
381 iw_local SMALLINT NOT NULL,
382 iw_trans SMALLINT NOT NULL DEFAULT 0
383 );
384
385
386 CREATE TABLE querycache (
387 qc_type TEXT NOT NULL,
388 qc_value INTEGER NOT NULL,
389 qc_namespace SMALLINT NOT NULL,
390 qc_title TEXT NOT NULL
391 );
392 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
393
394 CREATE TABLE querycache_info (
395 qci_type TEXT UNIQUE,
396 qci_timestamp TIMESTAMPTZ NULL
397 );
398
399 CREATE TABLE querycachetwo (
400 qcc_type TEXT NOT NULL,
401 qcc_value INTEGER NOT NULL DEFAULT 0,
402 qcc_namespace INTEGER NOT NULL DEFAULT 0,
403 qcc_title TEXT NOT NULL DEFAULT '',
404 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
405 qcc_titletwo TEXT NOT NULL DEFAULT ''
406 );
407 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
408 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
409 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
410
411 CREATE TABLE objectcache (
412 keyname TEXT UNIQUE,
413 value BYTEA NOT NULL DEFAULT '',
414 exptime TIMESTAMPTZ NOT NULL
415 );
416 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
417
418 CREATE TABLE transcache (
419 tc_url TEXT NOT NULL UNIQUE,
420 tc_contents TEXT NOT NULL,
421 tc_time TIMESTAMPTZ NOT NULL
422 );
423
424
425 CREATE SEQUENCE log_log_id_seq;
426 CREATE TABLE logging (
427 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('log_log_id_seq'),
428 log_type TEXT NOT NULL,
429 log_action TEXT NOT NULL,
430 log_timestamp TIMESTAMPTZ NOT NULL,
431 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
432 log_namespace SMALLINT NOT NULL,
433 log_title TEXT NOT NULL,
434 log_comment TEXT,
435 log_params TEXT,
436 log_deleted SMALLINT NOT NULL DEFAULT 0
437 );
438 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
439 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
440 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
441
442
443 CREATE SEQUENCE trackbacks_tb_id_seq;
444 CREATE TABLE trackbacks (
445 tb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
446 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
447 tb_title TEXT NOT NULL,
448 tb_url TEXT NOT NULL,
449 tb_ex TEXT,
450 tb_name TEXT
451 );
452 CREATE INDEX trackback_page ON trackbacks (tb_page);
453
454
455 CREATE SEQUENCE job_job_id_seq;
456 CREATE TABLE job (
457 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
458 job_cmd TEXT NOT NULL,
459 job_namespace SMALLINT NOT NULL,
460 job_title TEXT NOT NULL,
461 job_params TEXT NOT NULL
462 );
463 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
464
465 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
466 -- Note: if version 8.3 or higher, we remove the 'default' arg
467 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
468
469 ALTER TABLE page ADD titlevector tsvector;
470 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
471 $mw$
472 BEGIN
473 IF TG_OP = 'INSERT' THEN
474 NEW.titlevector = to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
475 ELSIF NEW.page_title != OLD.page_title THEN
476 NEW.titlevector := to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
477 END IF;
478 RETURN NEW;
479 END;
480 $mw$;
481
482 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
483 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
484
485
486 ALTER TABLE pagecontent ADD textvector tsvector;
487 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
488 $mw$
489 BEGIN
490 IF TG_OP = 'INSERT' THEN
491 NEW.textvector = to_tsvector('default',NEW.old_text);
492 ELSIF NEW.old_text != OLD.old_text THEN
493 NEW.textvector := to_tsvector('default',NEW.old_text);
494 END IF;
495 RETURN NEW;
496 END;
497 $mw$;
498
499 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
500 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
501
502 -- These are added by the setup script due to version compatibility issues
503 -- If using 8.1, we switch from "gin" to "gist"
504
505 CREATE INDEX ts2_page_title ON page USING gin(titlevector);
506 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
507
508 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
509 $mw$
510 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
511 SELECT 1;
512 $mw$;
513
514 -- This table is not used unless profiling is turned on
515 CREATE TABLE profiling (
516 pf_count INTEGER NOT NULL DEFAULT 0,
517 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
518 pf_name TEXT NOT NULL,
519 pf_server TEXT NULL
520 );
521 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
522
523 CREATE TABLE protected_titles (
524 pt_namespace SMALLINT NOT NULL,
525 pt_title TEXT NOT NULL,
526 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
527 pt_reason TEXT NULL,
528 pt_timestamp TIMESTAMPTZ NOT NULL,
529 pt_expiry TIMESTAMPTZ NULL,
530 pt_create_perm TEXT NOT NULL DEFAULT ''
531 );
532 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
533
534
535 CREATE TABLE updatelog (
536 ul_key TEXT NOT NULL PRIMARY KEY
537 );
538
539
540 CREATE SEQUENCE category_id_seq;
541 CREATE TABLE category (
542 cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_id_seq'),
543 cat_title TEXT NOT NULL,
544 cat_pages INTEGER NOT NULL DEFAULT 0,
545 cat_subcats INTEGER NOT NULL DEFAULT 0,
546 cat_files INTEGER NOT NULL DEFAULT 0,
547 cat_hidden SMALLINT NOT NULL DEFAULT 0
548 );
549 CREATE UNIQUE INDEX category_title ON category(cat_title);
550 CREATE INDEX category_pages ON category(cat_pages);
551
552 CREATE TABLE mediawiki_version (
553 type TEXT NOT NULL,
554 mw_version TEXT NOT NULL,
555 notes TEXT NULL,
556
557 pg_version TEXT NULL,
558 pg_dbname TEXT NULL,
559 pg_user TEXT NULL,
560 pg_port TEXT NULL,
561 mw_schema TEXT NULL,
562 ts2_schema TEXT NULL,
563 ctype TEXT NULL,
564
565 sql_version TEXT NULL,
566 sql_date TEXT NULL,
567 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
568 );
569
570 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
571 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
572