Added one-time promote support via Autopromote::autopromoteOnceHook function. This...
[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 DROP SEQUENCE IF EXISTS user_user_id_seq CASCADE;
13 DROP SEQUENCE IF EXISTS page_page_id_seq CASCADE;
14 DROP SEQUENCE IF EXISTS revision_rev_id_seq CASCADE;
15 DROP SEQUENCE IF EXISTS page_restrictions_id_seq CASCADE;
16 DROP SEQUENCE IF EXISTS ipblocks_ipb_id_seq CASCADE;
17 DROP SEQUENCE IF EXISTS recentchanges_rc_id_seq CASCADE;
18 DROP SEQUENCE IF EXISTS logging_log_id_seq CASCADE;
19 DROP SEQUENCE IF EXISTS trackbacks_tb_id_seq CASCADE;
20 DROP SEQUENCE IF EXISTS job_job_id_seq CASCADE;
21 DROP SEQUENCE IF EXISTS category_cat_id_seq CASCADE;
22 DROP FUNCTION IF EXISTS page_deleted() CASCADE;
23 DROP FUNCTION IF EXISTS ts2_page_title() CASCADE;
24 DROP FUNCTION IF EXISTS ts2_page_text() CASCADE;
25 DROP FUNCTION IF EXISTS add_interwiki(TEXT,INT,SMALLINT) CASCADE;
26
27 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
28 CREATE TABLE mwuser ( -- replace reserved word 'user'
29 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
30 user_name TEXT NOT NULL UNIQUE,
31 user_real_name TEXT,
32 user_password TEXT,
33 user_newpassword TEXT,
34 user_newpass_time TIMESTAMPTZ,
35 user_token TEXT,
36 user_email TEXT,
37 user_email_token TEXT,
38 user_email_token_expires TIMESTAMPTZ,
39 user_email_authenticated TIMESTAMPTZ,
40 user_options TEXT,
41 user_touched TIMESTAMPTZ,
42 user_registration TIMESTAMPTZ,
43 user_editcount INTEGER
44 );
45 CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
46
47 -- Create a dummy user to satisfy fk contraints especially with revisions
48 INSERT INTO mwuser
49 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
50
51 CREATE TABLE user_groups (
52 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
53 ug_group TEXT NOT NULL
54 );
55 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
56
57 CREATE TABLE user_former_groups (
58 ufg_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
59 ufg_group TEXT NOT NULL
60 );
61 CREATE UNIQUE INDEX user_former_groups_unique ON user_former_groups (ufg_user, ufg_group);
62
63 CREATE TABLE user_newtalk (
64 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
65 user_ip TEXT NULL,
66 user_last_timestamp TIMESTAMPTZ
67 );
68 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
69 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
70
71
72 CREATE SEQUENCE page_page_id_seq;
73 CREATE TABLE page (
74 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
75 page_namespace SMALLINT NOT NULL,
76 page_title TEXT NOT NULL,
77 page_restrictions TEXT,
78 page_counter BIGINT NOT NULL DEFAULT 0,
79 page_is_redirect SMALLINT NOT NULL DEFAULT 0,
80 page_is_new SMALLINT NOT NULL DEFAULT 0,
81 page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(),
82 page_touched TIMESTAMPTZ,
83 page_latest INTEGER NOT NULL, -- FK?
84 page_len INTEGER NOT NULL
85 );
86 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
87 CREATE INDEX page_main_title ON page (page_title text_pattern_ops) WHERE page_namespace = 0;
88 CREATE INDEX page_talk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 1;
89 CREATE INDEX page_user_title ON page (page_title text_pattern_ops) WHERE page_namespace = 2;
90 CREATE INDEX page_utalk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 3;
91 CREATE INDEX page_project_title ON page (page_title text_pattern_ops) WHERE page_namespace = 4;
92 CREATE INDEX page_mediawiki_title ON page (page_title text_pattern_ops) WHERE page_namespace = 8;
93 CREATE INDEX page_random_idx ON page (page_random);
94 CREATE INDEX page_len_idx ON page (page_len);
95
96 CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS
97 $mw$
98 BEGIN
99 DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title;
100 RETURN NULL;
101 END;
102 $mw$;
103
104 CREATE TRIGGER page_deleted AFTER DELETE ON page
105 FOR EACH ROW EXECUTE PROCEDURE page_deleted();
106
107 CREATE SEQUENCE revision_rev_id_seq;
108 CREATE TABLE revision (
109 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('revision_rev_id_seq'),
110 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
111 rev_text_id INTEGER NULL, -- FK
112 rev_comment TEXT,
113 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED,
114 rev_user_text TEXT NOT NULL,
115 rev_timestamp TIMESTAMPTZ NOT NULL,
116 rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
117 rev_deleted SMALLINT NOT NULL DEFAULT 0,
118 rev_len INTEGER NULL,
119 rev_parent_id INTEGER NULL
120 );
121 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
122 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
123 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
124 CREATE INDEX rev_user_idx ON revision (rev_user);
125 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
126
127
128 CREATE SEQUENCE text_old_id_seq;
129 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
130 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_seq'),
131 old_text TEXT,
132 old_flags TEXT
133 );
134
135
136 CREATE SEQUENCE page_restrictions_pr_id_seq;
137 CREATE TABLE page_restrictions (
138 pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('page_restrictions_pr_id_seq'),
139 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
140 pr_type TEXT NOT NULL,
141 pr_level TEXT NOT NULL,
142 pr_cascade SMALLINT NOT NULL,
143 pr_user INTEGER NULL,
144 pr_expiry TIMESTAMPTZ NULL
145 );
146 ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
147
148 CREATE TABLE page_props (
149 pp_page INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
150 pp_propname TEXT NOT NULL,
151 pp_value TEXT NOT NULL
152 );
153 ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
154 CREATE INDEX page_props_propname ON page_props (pp_propname);
155
156 CREATE TABLE archive (
157 ar_namespace SMALLINT NOT NULL,
158 ar_title TEXT NOT NULL,
159 ar_text TEXT, -- technically should be bytea, but not used anymore
160 ar_page_id INTEGER NULL,
161 ar_parent_id INTEGER NULL,
162 ar_comment TEXT,
163 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
164 ar_user_text TEXT NOT NULL,
165 ar_timestamp TIMESTAMPTZ NOT NULL,
166 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
167 ar_flags TEXT,
168 ar_rev_id INTEGER,
169 ar_text_id INTEGER,
170 ar_deleted SMALLINT NOT NULL DEFAULT 0,
171 ar_len INTEGER NULL
172 );
173 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
174 CREATE INDEX archive_user_text ON archive (ar_user_text);
175
176
177 CREATE TABLE redirect (
178 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
179 rd_namespace SMALLINT NOT NULL,
180 rd_title TEXT NOT NULL,
181 rd_interwiki TEXT NULL,
182 rd_fragment TEXT NULL
183 );
184 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
185
186
187 CREATE TABLE pagelinks (
188 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
189 pl_namespace SMALLINT NOT NULL,
190 pl_title TEXT NOT NULL
191 );
192 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
193 CREATE INDEX pagelinks_title ON pagelinks (pl_title);
194
195 CREATE TABLE templatelinks (
196 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
197 tl_namespace SMALLINT NOT NULL,
198 tl_title TEXT NOT NULL
199 );
200 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
201 CREATE INDEX templatelinks_from ON templatelinks (tl_from);
202
203 CREATE TABLE imagelinks (
204 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
205 il_to TEXT NOT NULL
206 );
207 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
208
209 CREATE TABLE categorylinks (
210 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
211 cl_to TEXT NOT NULL,
212 cl_sortkey TEXT NULL,
213 cl_timestamp TIMESTAMPTZ NOT NULL,
214 cl_sortkey_prefix TEXT NOT NULL DEFAULT '',
215 cl_collation TEXT NOT NULL DEFAULT 0,
216 cl_type TEXT NOT NULL DEFAULT 'page'
217 );
218 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
219 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
220
221 CREATE TABLE externallinks (
222 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
223 el_to TEXT NOT NULL,
224 el_index TEXT NOT NULL
225 );
226 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
227 CREATE INDEX externallinks_index ON externallinks (el_index);
228
229 CREATE TABLE external_user (
230 eu_local_id INTEGER NOT NULL PRIMARY KEY,
231 eu_external_id TEXT
232 );
233
234 CREATE UNIQUE INDEX eu_external_id ON external_user (eu_external_id);
235
236 CREATE TABLE langlinks (
237 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
238 ll_lang TEXT,
239 ll_title TEXT
240 );
241 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
242 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
243
244
245 CREATE TABLE site_stats (
246 ss_row_id INTEGER NOT NULL UNIQUE,
247 ss_total_views INTEGER DEFAULT 0,
248 ss_total_edits INTEGER DEFAULT 0,
249 ss_good_articles INTEGER DEFAULT 0,
250 ss_total_pages INTEGER DEFAULT -1,
251 ss_users INTEGER DEFAULT -1,
252 ss_active_users INTEGER DEFAULT -1,
253 ss_admins INTEGER DEFAULT -1,
254 ss_images INTEGER DEFAULT 0
255 );
256
257 CREATE TABLE hitcounter (
258 hc_id BIGINT NOT NULL
259 );
260
261
262 CREATE SEQUENCE ipblocks_ipb_id_seq;
263 CREATE TABLE ipblocks (
264 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_seq'),
265 ipb_address TEXT NULL,
266 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
267 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
268 ipb_by_text TEXT NOT NULL DEFAULT '',
269 ipb_reason TEXT NOT NULL,
270 ipb_timestamp TIMESTAMPTZ NOT NULL,
271 ipb_auto SMALLINT NOT NULL DEFAULT 0,
272 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
273 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
274 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
275 ipb_expiry TIMESTAMPTZ NOT NULL,
276 ipb_range_start TEXT,
277 ipb_range_end TEXT,
278 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
279 ipb_block_email SMALLINT NOT NULL DEFAULT 0,
280 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0
281
282 );
283 CREATE UNIQUE INDEX ipb_address_unique ON ipblocks (ipb_address,ipb_user,ipb_auto,ipb_anon_only);
284 CREATE INDEX ipb_user ON ipblocks (ipb_user);
285 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
286
287
288 CREATE TABLE image (
289 img_name TEXT NOT NULL PRIMARY KEY,
290 img_size INTEGER NOT NULL,
291 img_width INTEGER NOT NULL,
292 img_height INTEGER NOT NULL,
293 img_metadata BYTEA NOT NULL DEFAULT '',
294 img_bits SMALLINT,
295 img_media_type TEXT,
296 img_major_mime TEXT DEFAULT 'unknown',
297 img_minor_mime TEXT DEFAULT 'unknown',
298 img_description TEXT NOT NULL,
299 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
300 img_user_text TEXT NOT NULL,
301 img_timestamp TIMESTAMPTZ,
302 img_sha1 TEXT NOT NULL DEFAULT ''
303 );
304 CREATE INDEX img_size_idx ON image (img_size);
305 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
306 CREATE INDEX img_sha1 ON image (img_sha1);
307
308 CREATE TABLE oldimage (
309 oi_name TEXT NOT NULL,
310 oi_archive_name TEXT NOT NULL,
311 oi_size INTEGER NOT NULL,
312 oi_width INTEGER NOT NULL,
313 oi_height INTEGER NOT NULL,
314 oi_bits SMALLINT NULL,
315 oi_description TEXT,
316 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
317 oi_user_text TEXT NOT NULL,
318 oi_timestamp TIMESTAMPTZ NULL,
319 oi_metadata BYTEA NOT NULL DEFAULT '',
320 oi_media_type TEXT NULL,
321 oi_major_mime TEXT NULL DEFAULT 'unknown',
322 oi_minor_mime TEXT NULL DEFAULT 'unknown',
323 oi_deleted SMALLINT NOT NULL DEFAULT 0,
324 oi_sha1 TEXT NOT NULL DEFAULT ''
325 );
326 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;
327 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
328 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
329 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
330
331
332 CREATE SEQUENCE filearchive_fa_id_seq;
333 CREATE TABLE filearchive (
334 fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
335 fa_name TEXT NOT NULL,
336 fa_archive_name TEXT,
337 fa_storage_group TEXT,
338 fa_storage_key TEXT,
339 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
340 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
341 fa_deleted_reason TEXT,
342 fa_size INTEGER NOT NULL,
343 fa_width INTEGER NOT NULL,
344 fa_height INTEGER NOT NULL,
345 fa_metadata BYTEA NOT NULL DEFAULT '',
346 fa_bits SMALLINT,
347 fa_media_type TEXT,
348 fa_major_mime TEXT DEFAULT 'unknown',
349 fa_minor_mime TEXT DEFAULT 'unknown',
350 fa_description TEXT NOT NULL,
351 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
352 fa_user_text TEXT NOT NULL,
353 fa_timestamp TIMESTAMPTZ,
354 fa_deleted SMALLINT NOT NULL DEFAULT 0
355 );
356 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
357 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
358 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
359 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
360
361
362 CREATE SEQUENCE recentchanges_rc_id_seq;
363 CREATE TABLE recentchanges (
364 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('recentchanges_rc_id_seq'),
365 rc_timestamp TIMESTAMPTZ NOT NULL,
366 rc_cur_time TIMESTAMPTZ NOT NULL,
367 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
368 rc_user_text TEXT NOT NULL,
369 rc_namespace SMALLINT NOT NULL,
370 rc_title TEXT NOT NULL,
371 rc_comment TEXT,
372 rc_minor SMALLINT NOT NULL DEFAULT 0,
373 rc_bot SMALLINT NOT NULL DEFAULT 0,
374 rc_new SMALLINT NOT NULL DEFAULT 0,
375 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
376 rc_this_oldid INTEGER NOT NULL,
377 rc_last_oldid INTEGER NOT NULL,
378 rc_type SMALLINT NOT NULL DEFAULT 0,
379 rc_moved_to_ns SMALLINT,
380 rc_moved_to_title TEXT,
381 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
382 rc_ip CIDR,
383 rc_old_len INTEGER,
384 rc_new_len INTEGER,
385 rc_deleted SMALLINT NOT NULL DEFAULT 0,
386 rc_logid INTEGER NOT NULL DEFAULT 0,
387 rc_log_type TEXT,
388 rc_log_action TEXT,
389 rc_params TEXT
390 );
391 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
392 CREATE INDEX rc_timestamp_bot ON recentchanges (rc_timestamp) WHERE rc_bot = 0;
393 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
394 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
395 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
396 CREATE INDEX rc_ip ON recentchanges (rc_ip);
397
398
399 CREATE TABLE watchlist (
400 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
401 wl_namespace SMALLINT NOT NULL DEFAULT 0,
402 wl_title TEXT NOT NULL,
403 wl_notificationtimestamp TIMESTAMPTZ
404 );
405 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
406 CREATE INDEX wl_user ON watchlist (wl_user);
407
408
409 CREATE TABLE interwiki (
410 iw_prefix TEXT NOT NULL UNIQUE,
411 iw_url TEXT NOT NULL,
412 iw_local SMALLINT NOT NULL,
413 iw_trans SMALLINT NOT NULL DEFAULT 0,
414 iw_api TEXT NOT NULL DEFAULT '',
415 iw_wikiid TEXT NOT NULL DEFAULT ''
416 );
417
418
419 CREATE TABLE querycache (
420 qc_type TEXT NOT NULL,
421 qc_value INTEGER NOT NULL,
422 qc_namespace SMALLINT NOT NULL,
423 qc_title TEXT NOT NULL
424 );
425 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
426
427 CREATE TABLE querycache_info (
428 qci_type TEXT UNIQUE,
429 qci_timestamp TIMESTAMPTZ NULL
430 );
431
432 CREATE TABLE querycachetwo (
433 qcc_type TEXT NOT NULL,
434 qcc_value INTEGER NOT NULL DEFAULT 0,
435 qcc_namespace INTEGER NOT NULL DEFAULT 0,
436 qcc_title TEXT NOT NULL DEFAULT '',
437 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
438 qcc_titletwo TEXT NOT NULL DEFAULT ''
439 );
440 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
441 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
442 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
443
444 CREATE TABLE objectcache (
445 keyname TEXT UNIQUE,
446 value BYTEA NOT NULL DEFAULT '',
447 exptime TIMESTAMPTZ NOT NULL
448 );
449 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
450
451 CREATE TABLE transcache (
452 tc_url TEXT NOT NULL UNIQUE,
453 tc_contents TEXT NOT NULL,
454 tc_time TIMESTAMPTZ NOT NULL
455 );
456
457
458 CREATE SEQUENCE logging_log_id_seq;
459 CREATE TABLE logging (
460 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('logging_log_id_seq'),
461 log_type TEXT NOT NULL,
462 log_action TEXT NOT NULL,
463 log_timestamp TIMESTAMPTZ NOT NULL,
464 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
465 log_namespace SMALLINT NOT NULL,
466 log_title TEXT NOT NULL,
467 log_comment TEXT,
468 log_params TEXT,
469 log_deleted SMALLINT NOT NULL DEFAULT 0,
470 log_user_text TEXT NOT NULL DEFAULT '',
471 log_page INTEGER
472 );
473 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
474 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
475 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
476 CREATE INDEX logging_times ON logging (log_timestamp);
477 CREATE INDEX logging_user_type_time ON logging (log_user, log_type, log_timestamp);
478 CREATE INDEX logging_page_id_time ON logging (log_page, log_timestamp);
479
480 CREATE TABLE log_search (
481 ls_field TEXT NOT NULL,
482 ls_value TEXT NOT NULL,
483 ls_log_id INTEGER NOT NULL DEFAULT 0,
484 PRIMARY KEY (ls_field,ls_value,ls_log_id)
485 );
486 CREATE INDEX ls_log_id ON log_search (ls_log_id);
487
488 CREATE SEQUENCE trackbacks_tb_id_seq;
489 CREATE TABLE trackbacks (
490 tb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
491 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
492 tb_title TEXT NOT NULL,
493 tb_url TEXT NOT NULL,
494 tb_ex TEXT,
495 tb_name TEXT
496 );
497 CREATE INDEX trackback_page ON trackbacks (tb_page);
498
499
500 CREATE SEQUENCE job_job_id_seq;
501 CREATE TABLE job (
502 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
503 job_cmd TEXT NOT NULL,
504 job_namespace SMALLINT NOT NULL,
505 job_title TEXT NOT NULL,
506 job_params TEXT NOT NULL
507 );
508 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
509
510 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
511 -- Version 8.3 or higher only. Previous versions would need another parmeter for to_tsvector.
512 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
513
514 ALTER TABLE page ADD titlevector tsvector;
515 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
516 $mw$
517 BEGIN
518 IF TG_OP = 'INSERT' THEN
519 NEW.titlevector = to_tsvector(REPLACE(NEW.page_title,'/',' '));
520 ELSIF NEW.page_title != OLD.page_title THEN
521 NEW.titlevector := to_tsvector(REPLACE(NEW.page_title,'/',' '));
522 END IF;
523 RETURN NEW;
524 END;
525 $mw$;
526
527 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
528 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
529
530
531 ALTER TABLE pagecontent ADD textvector tsvector;
532 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
533 $mw$
534 BEGIN
535 IF TG_OP = 'INSERT' THEN
536 NEW.textvector = to_tsvector(NEW.old_text);
537 ELSIF NEW.old_text != OLD.old_text THEN
538 NEW.textvector := to_tsvector(NEW.old_text);
539 END IF;
540 RETURN NEW;
541 END;
542 $mw$;
543
544 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
545 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
546
547 -- These are added by the setup script due to version compatibility issues
548 -- If using 8.1, we switch from "gin" to "gist"
549
550 CREATE INDEX ts2_page_title ON page USING gin(titlevector);
551 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
552
553 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
554 $mw$
555 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
556 SELECT 1;
557 $mw$;
558
559 -- This table is not used unless profiling is turned on
560 CREATE TABLE profiling (
561 pf_count INTEGER NOT NULL DEFAULT 0,
562 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
563 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
564 pf_name TEXT NOT NULL,
565 pf_server TEXT NULL
566 );
567 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
568
569 CREATE TABLE protected_titles (
570 pt_namespace SMALLINT NOT NULL,
571 pt_title TEXT NOT NULL,
572 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
573 pt_reason TEXT NULL,
574 pt_timestamp TIMESTAMPTZ NOT NULL,
575 pt_expiry TIMESTAMPTZ NULL,
576 pt_create_perm TEXT NOT NULL DEFAULT ''
577 );
578 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
579
580
581 CREATE TABLE updatelog (
582 ul_key TEXT NOT NULL PRIMARY KEY,
583 ul_value TEXT
584 );
585
586
587 CREATE SEQUENCE category_cat_id_seq;
588 CREATE TABLE category (
589 cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_cat_id_seq'),
590 cat_title TEXT NOT NULL,
591 cat_pages INTEGER NOT NULL DEFAULT 0,
592 cat_subcats INTEGER NOT NULL DEFAULT 0,
593 cat_files INTEGER NOT NULL DEFAULT 0,
594 cat_hidden SMALLINT NOT NULL DEFAULT 0
595 );
596 CREATE UNIQUE INDEX category_title ON category(cat_title);
597 CREATE INDEX category_pages ON category(cat_pages);
598
599 CREATE TABLE change_tag (
600 ct_rc_id INTEGER NULL,
601 ct_log_id INTEGER NULL,
602 ct_rev_id INTEGER NULL,
603 ct_tag TEXT NOT NULL,
604 ct_params TEXT NULL
605 );
606 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag(ct_rc_id,ct_tag);
607 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag(ct_log_id,ct_tag);
608 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag(ct_rev_id,ct_tag);
609 CREATE INDEX change_tag_tag_id ON change_tag(ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
610
611 CREATE TABLE tag_summary (
612 ts_rc_id INTEGER NULL,
613 ts_log_id INTEGER NULL,
614 ts_rev_id INTEGER NULL,
615 ts_tags TEXT NOT NULL
616 );
617 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary(ts_rc_id);
618 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary(ts_log_id);
619 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary(ts_rev_id);
620
621 CREATE TABLE valid_tag (
622 vt_tag TEXT NOT NULL PRIMARY KEY
623 );
624
625 CREATE TABLE user_properties (
626 up_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
627 up_property TEXT NOT NULL,
628 up_value TEXT
629 );
630 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
631 CREATE INDEX user_properties_property ON user_properties (up_property);
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);
639
640 CREATE TABLE iwlinks (
641 iwl_from INTEGER NOT NULL DEFAULT 0,
642 iwl_prefix TEXT NOT NULL DEFAULT '',
643 iwl_title TEXT NOT NULL DEFAULT ''
644 );
645 CREATE UNIQUE INDEX iwl_from ON iwlinks (iwl_from, iwl_prefix, iwl_title);
646 CREATE UNIQUE INDEX iwl_prefix_title_from ON iwlinks (iwl_prefix, iwl_title, iwl_from);
647
648 CREATE TABLE msg_resource (
649 mr_resource TEXT NOT NULL,
650 mr_lang TEXT NOT NULL,
651 mr_blob TEXT NOT NULL,
652 mr_timestamp TIMESTAMPTZ NOT NULL
653 );
654 CREATE UNIQUE INDEX mr_resource_lang ON msg_resource (mr_resource, mr_lang);
655
656 CREATE TABLE msg_resource_links (
657 mrl_resource TEXT NOT NULL,
658 mrl_message TEXT NOT NULL
659 );
660 CREATE UNIQUE INDEX mrl_message_resource ON msg_resource_links (mrl_message, mrl_resource);
661
662 CREATE TABLE module_deps (
663 md_module TEXT NOT NULL,
664 md_skin TEXT NOT NULL,
665 md_deps TEXT NOT NULL
666 );
667 CREATE UNIQUE INDEX md_module_skin ON module_deps (md_module, md_skin);