Make foreign key constraints DEFERRABLE INITIALLY DEFERRED when using Postgres as...
[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 DEFERRABLE INITIALLY DEFERRED,
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 DEFERRABLE INITIALLY DEFERRED,
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 revision_rev_id_seq;
86 CREATE TABLE revision (
87 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('revision_rev_id_seq'),
88 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
89 rev_text_id INTEGER NULL, -- FK
90 rev_comment TEXT,
91 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED,
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_seq;
107 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
108 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_seq'),
109 old_text TEXT,
110 old_flags TEXT
111 );
112
113
114 CREATE SEQUENCE page_restrictions_pr_id_seq;
115 CREATE TABLE page_restrictions (
116 pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('page_restrictions_pr_id_seq'),
117 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
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 DEFERRABLE INITIALLY DEFERRED,
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 DEFERRABLE INITIALLY DEFERRED,
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 DEFERRABLE INITIALLY DEFERRED,
157 rd_namespace SMALLINT NOT NULL,
158 rd_title TEXT NOT NULL,
159 rd_interwiki TEXT NULL,
160 rd_fragment TEXT NULL
161 );
162 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
163
164
165 CREATE TABLE pagelinks (
166 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
167 pl_namespace SMALLINT NOT NULL,
168 pl_title TEXT NOT NULL
169 );
170 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
171
172 CREATE TABLE templatelinks (
173 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
174 tl_namespace SMALLINT NOT NULL,
175 tl_title TEXT NOT NULL
176 );
177 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
178 CREATE INDEX templatelinks_from ON templatelinks (tl_from);
179
180 CREATE TABLE imagelinks (
181 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
182 il_to TEXT NOT NULL
183 );
184 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
185
186 CREATE TABLE categorylinks (
187 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
188 cl_to TEXT NOT NULL,
189 cl_sortkey TEXT,
190 cl_timestamp TIMESTAMPTZ NOT NULL
191 );
192 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
193 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
194
195 CREATE TABLE externallinks (
196 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
197 el_to TEXT NOT NULL,
198 el_index TEXT NOT NULL
199 );
200 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
201 CREATE INDEX externallinks_index ON externallinks (el_index);
202
203 CREATE TABLE external_user (
204 eu_local_id INTEGER NOT NULL PRIMARY KEY,
205 eu_external_id TEXT
206 );
207
208 CREATE UNIQUE INDEX eu_external_id ON external_user (eu_external_id);
209
210 CREATE TABLE langlinks (
211 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
212 ll_lang TEXT,
213 ll_title TEXT
214 );
215 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
216 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
217
218
219 CREATE TABLE site_stats (
220 ss_row_id INTEGER NOT NULL UNIQUE,
221 ss_total_views INTEGER DEFAULT 0,
222 ss_total_edits INTEGER DEFAULT 0,
223 ss_good_articles INTEGER DEFAULT 0,
224 ss_total_pages INTEGER DEFAULT -1,
225 ss_users INTEGER DEFAULT -1,
226 ss_active_users INTEGER DEFAULT -1,
227 ss_admins INTEGER DEFAULT -1,
228 ss_images INTEGER DEFAULT 0
229 );
230
231 CREATE TABLE hitcounter (
232 hc_id BIGINT NOT NULL
233 );
234
235
236 CREATE SEQUENCE ipblocks_ipb_id_seq;
237 CREATE TABLE ipblocks (
238 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_seq'),
239 ipb_address TEXT NULL,
240 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
241 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
242 ipb_by_text TEXT NOT NULL DEFAULT '',
243 ipb_reason TEXT NOT NULL,
244 ipb_timestamp TIMESTAMPTZ NOT NULL,
245 ipb_auto SMALLINT NOT NULL DEFAULT 0,
246 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
247 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
248 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
249 ipb_expiry TIMESTAMPTZ NOT NULL,
250 ipb_range_start TEXT,
251 ipb_range_end TEXT,
252 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
253 ipb_block_email SMALLINT NOT NULL DEFAULT 0,
254 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0
255
256 );
257 CREATE UNIQUE INDEX ipb_address_unique ON ipblocks (ipb_address,ipb_user,ipb_auto,ipb_anon_only);
258 CREATE INDEX ipb_user ON ipblocks (ipb_user);
259 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
260
261
262 CREATE TABLE image (
263 img_name TEXT NOT NULL PRIMARY KEY,
264 img_size INTEGER NOT NULL,
265 img_width INTEGER NOT NULL,
266 img_height INTEGER NOT NULL,
267 img_metadata BYTEA NOT NULL DEFAULT '',
268 img_bits SMALLINT,
269 img_media_type TEXT,
270 img_major_mime TEXT DEFAULT 'unknown',
271 img_minor_mime TEXT DEFAULT 'unknown',
272 img_description TEXT NOT NULL,
273 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
274 img_user_text TEXT NOT NULL,
275 img_timestamp TIMESTAMPTZ,
276 img_sha1 TEXT NOT NULL DEFAULT ''
277 );
278 CREATE INDEX img_size_idx ON image (img_size);
279 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
280 CREATE INDEX img_sha1 ON image (img_sha1);
281
282 CREATE TABLE oldimage (
283 oi_name TEXT NOT NULL,
284 oi_archive_name TEXT NOT NULL,
285 oi_size INTEGER NOT NULL,
286 oi_width INTEGER NOT NULL,
287 oi_height INTEGER NOT NULL,
288 oi_bits SMALLINT NULL,
289 oi_description TEXT,
290 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
291 oi_user_text TEXT NOT NULL,
292 oi_timestamp TIMESTAMPTZ NULL,
293 oi_metadata BYTEA NOT NULL DEFAULT '',
294 oi_media_type TEXT NULL,
295 oi_major_mime TEXT NULL DEFAULT 'unknown',
296 oi_minor_mime TEXT NULL DEFAULT 'unknown',
297 oi_deleted SMALLINT NOT NULL DEFAULT 0,
298 oi_sha1 TEXT NOT NULL DEFAULT ''
299 );
300 ALTER TABLE oldimage ADD CONSTRAINT oldimage_oi_name_fkey_cascaded FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
301 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
302 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
303 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
304
305
306 CREATE SEQUENCE filearchive_fa_id_seq;
307 CREATE TABLE filearchive (
308 fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
309 fa_name TEXT NOT NULL,
310 fa_archive_name TEXT,
311 fa_storage_group TEXT,
312 fa_storage_key TEXT,
313 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
314 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
315 fa_deleted_reason TEXT,
316 fa_size INTEGER NOT NULL,
317 fa_width INTEGER NOT NULL,
318 fa_height INTEGER NOT NULL,
319 fa_metadata BYTEA NOT NULL DEFAULT '',
320 fa_bits SMALLINT,
321 fa_media_type TEXT,
322 fa_major_mime TEXT DEFAULT 'unknown',
323 fa_minor_mime TEXT DEFAULT 'unknown',
324 fa_description TEXT NOT NULL,
325 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
326 fa_user_text TEXT NOT NULL,
327 fa_timestamp TIMESTAMPTZ,
328 fa_deleted SMALLINT NOT NULL DEFAULT 0
329 );
330 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
331 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
332 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
333 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
334
335
336 CREATE SEQUENCE recentchanges_rc_id_seq;
337 CREATE TABLE recentchanges (
338 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('recentchanges_rc_id_seq'),
339 rc_timestamp TIMESTAMPTZ NOT NULL,
340 rc_cur_time TIMESTAMPTZ NOT NULL,
341 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
342 rc_user_text TEXT NOT NULL,
343 rc_namespace SMALLINT NOT NULL,
344 rc_title TEXT NOT NULL,
345 rc_comment TEXT,
346 rc_minor SMALLINT NOT NULL DEFAULT 0,
347 rc_bot SMALLINT NOT NULL DEFAULT 0,
348 rc_new SMALLINT NOT NULL DEFAULT 0,
349 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
350 rc_this_oldid INTEGER NOT NULL,
351 rc_last_oldid INTEGER NOT NULL,
352 rc_type SMALLINT NOT NULL DEFAULT 0,
353 rc_moved_to_ns SMALLINT,
354 rc_moved_to_title TEXT,
355 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
356 rc_ip CIDR,
357 rc_old_len INTEGER,
358 rc_new_len INTEGER,
359 rc_deleted SMALLINT NOT NULL DEFAULT 0,
360 rc_logid INTEGER NOT NULL DEFAULT 0,
361 rc_log_type TEXT,
362 rc_log_action TEXT,
363 rc_params TEXT
364 );
365 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
366 CREATE INDEX rc_timestamp_bot ON recentchanges (rc_timestamp) WHERE rc_bot = 0;
367 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
368 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
369 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
370 CREATE INDEX rc_ip ON recentchanges (rc_ip);
371
372
373 CREATE TABLE watchlist (
374 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
375 wl_namespace SMALLINT NOT NULL DEFAULT 0,
376 wl_title TEXT NOT NULL,
377 wl_notificationtimestamp TIMESTAMPTZ
378 );
379 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
380 CREATE INDEX wl_user ON watchlist (wl_user);
381
382 CREATE TABLE math (
383 math_inputhash BYTEA NOT NULL UNIQUE,
384 math_outputhash BYTEA NOT NULL,
385 math_html_conservativeness SMALLINT NOT NULL,
386 math_html TEXT,
387 math_mathml TEXT
388 );
389
390
391 CREATE TABLE interwiki (
392 iw_prefix TEXT NOT NULL UNIQUE,
393 iw_url TEXT NOT NULL,
394 iw_local SMALLINT NOT NULL,
395 iw_trans SMALLINT NOT NULL DEFAULT 0
396 );
397
398
399 CREATE TABLE querycache (
400 qc_type TEXT NOT NULL,
401 qc_value INTEGER NOT NULL,
402 qc_namespace SMALLINT NOT NULL,
403 qc_title TEXT NOT NULL
404 );
405 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
406
407 CREATE TABLE querycache_info (
408 qci_type TEXT UNIQUE,
409 qci_timestamp TIMESTAMPTZ NULL
410 );
411
412 CREATE TABLE querycachetwo (
413 qcc_type TEXT NOT NULL,
414 qcc_value INTEGER NOT NULL DEFAULT 0,
415 qcc_namespace INTEGER NOT NULL DEFAULT 0,
416 qcc_title TEXT NOT NULL DEFAULT '',
417 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
418 qcc_titletwo TEXT NOT NULL DEFAULT ''
419 );
420 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
421 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
422 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
423
424 CREATE TABLE objectcache (
425 keyname TEXT UNIQUE,
426 value BYTEA NOT NULL DEFAULT '',
427 exptime TIMESTAMPTZ NOT NULL
428 );
429 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
430
431 CREATE TABLE transcache (
432 tc_url TEXT NOT NULL UNIQUE,
433 tc_contents TEXT NOT NULL,
434 tc_time TIMESTAMPTZ NOT NULL
435 );
436
437
438 CREATE SEQUENCE logging_log_id_seq;
439 CREATE TABLE logging (
440 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('logging_log_id_seq'),
441 log_type TEXT NOT NULL,
442 log_action TEXT NOT NULL,
443 log_timestamp TIMESTAMPTZ NOT NULL,
444 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
445 log_namespace SMALLINT NOT NULL,
446 log_title TEXT NOT NULL,
447 log_comment TEXT,
448 log_params TEXT,
449 log_deleted SMALLINT NOT NULL DEFAULT 0,
450 log_user_text TEXT NOT NULL DEFAULT '',
451 log_page INTEGER
452 );
453 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
454 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
455 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
456 CREATE INDEX logging_times ON logging (log_timestamp);
457 CREATE INDEX logging_user_type_time ON logging (log_user, log_type, log_timestamp);
458 CREATE INDEX logging_page_id_time ON logging (log_page, log_timestamp);
459
460 CREATE TABLE log_search (
461 ls_field TEXT NOT NULL,
462 ls_value TEXT NOT NULL,
463 ls_log_id INTEGER NOT NULL DEFAULT 0,
464 PRIMARY KEY (ls_field,ls_value,ls_log_id)
465 );
466 CREATE INDEX ls_log_id ON log_search (ls_log_id);
467
468 CREATE SEQUENCE trackbacks_tb_id_seq;
469 CREATE TABLE trackbacks (
470 tb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
471 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
472 tb_title TEXT NOT NULL,
473 tb_url TEXT NOT NULL,
474 tb_ex TEXT,
475 tb_name TEXT
476 );
477 CREATE INDEX trackback_page ON trackbacks (tb_page);
478
479
480 CREATE SEQUENCE job_job_id_seq;
481 CREATE TABLE job (
482 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
483 job_cmd TEXT NOT NULL,
484 job_namespace SMALLINT NOT NULL,
485 job_title TEXT NOT NULL,
486 job_params TEXT NOT NULL
487 );
488 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
489
490 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
491 -- Note: if version 8.3 or higher, we remove the 'default' arg
492 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
493
494 ALTER TABLE page ADD titlevector tsvector;
495 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
496 $mw$
497 BEGIN
498 IF TG_OP = 'INSERT' THEN
499 NEW.titlevector = to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
500 ELSIF NEW.page_title != OLD.page_title THEN
501 NEW.titlevector := to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
502 END IF;
503 RETURN NEW;
504 END;
505 $mw$;
506
507 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
508 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
509
510
511 ALTER TABLE pagecontent ADD textvector tsvector;
512 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
513 $mw$
514 BEGIN
515 IF TG_OP = 'INSERT' THEN
516 NEW.textvector = to_tsvector('default',NEW.old_text);
517 ELSIF NEW.old_text != OLD.old_text THEN
518 NEW.textvector := to_tsvector('default',NEW.old_text);
519 END IF;
520 RETURN NEW;
521 END;
522 $mw$;
523
524 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
525 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
526
527 -- These are added by the setup script due to version compatibility issues
528 -- If using 8.1, we switch from "gin" to "gist"
529
530 CREATE INDEX ts2_page_title ON page USING gin(titlevector);
531 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
532
533 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
534 $mw$
535 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
536 SELECT 1;
537 $mw$;
538
539 -- This table is not used unless profiling is turned on
540 CREATE TABLE profiling (
541 pf_count INTEGER NOT NULL DEFAULT 0,
542 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
543 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
544 pf_name TEXT NOT NULL,
545 pf_server TEXT NULL
546 );
547 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
548
549 CREATE TABLE protected_titles (
550 pt_namespace SMALLINT NOT NULL,
551 pt_title TEXT NOT NULL,
552 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
553 pt_reason TEXT NULL,
554 pt_timestamp TIMESTAMPTZ NOT NULL,
555 pt_expiry TIMESTAMPTZ NULL,
556 pt_create_perm TEXT NOT NULL DEFAULT ''
557 );
558 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
559
560
561 CREATE TABLE updatelog (
562 ul_key TEXT NOT NULL PRIMARY KEY
563 );
564
565
566 CREATE SEQUENCE category_cat_id_seq;
567 CREATE TABLE category (
568 cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_cat_id_seq'),
569 cat_title TEXT NOT NULL,
570 cat_pages INTEGER NOT NULL DEFAULT 0,
571 cat_subcats INTEGER NOT NULL DEFAULT 0,
572 cat_files INTEGER NOT NULL DEFAULT 0,
573 cat_hidden SMALLINT NOT NULL DEFAULT 0
574 );
575 CREATE UNIQUE INDEX category_title ON category(cat_title);
576 CREATE INDEX category_pages ON category(cat_pages);
577
578 CREATE TABLE change_tag (
579 ct_rc_id INTEGER NULL,
580 ct_log_id INTEGER NULL,
581 ct_rev_id INTEGER NULL,
582 ct_tag TEXT NOT NULL,
583 ct_params TEXT NULL
584 );
585 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag(ct_rc_id,ct_tag);
586 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag(ct_log_id,ct_tag);
587 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag(ct_rev_id,ct_tag);
588 CREATE INDEX change_tag_tag_id ON change_tag(ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
589
590 CREATE TABLE tag_summary (
591 ts_rc_id INTEGER NULL,
592 ts_log_id INTEGER NULL,
593 ts_rev_id INTEGER NULL,
594 ts_tags TEXT NOT NULL
595 );
596 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary(ts_rc_id);
597 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary(ts_log_id);
598 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary(ts_rev_id);
599
600 CREATE TABLE valid_tag (
601 vt_tag TEXT NOT NULL PRIMARY KEY
602 );
603
604 CREATE TABLE user_properties (
605 up_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
606 up_property TEXT NOT NULL,
607 up_value TEXT
608 );
609 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
610 CREATE INDEX user_properties_property ON user_properties (up_property);
611
612 CREATE TABLE mediawiki_version (
613 type TEXT NOT NULL,
614 mw_version TEXT NOT NULL,
615 notes TEXT NULL,
616
617 pg_version TEXT NULL,
618 pg_dbname TEXT NULL,
619 pg_user TEXT NULL,
620 pg_port TEXT NULL,
621 mw_schema TEXT NULL,
622 ts2_schema TEXT NULL,
623 ctype TEXT NULL,
624
625 sql_version TEXT NULL,
626 sql_date TEXT NULL,
627 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
628 );
629
630 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
631 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
632
633 CREATE TABLE l10n_cache (
634 lc_lang TEXT NOT NULL,
635 lc_key TEXT NOT NULL,
636 lc_value TEXT NOT NULL
637 );
638 CREATE INDEX l10n_cache_lc_lang_key ON l10n_cache (lc_lang, lc_key);