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