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