Merge "wfProfileOut() for new return added in c6396 (c4e407c)"
[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 job_job_id_seq CASCADE;
20 DROP SEQUENCE IF EXISTS category_cat_id_seq CASCADE;
21 DROP FUNCTION IF EXISTS page_deleted() CASCADE;
22 DROP FUNCTION IF EXISTS ts2_page_title() CASCADE;
23 DROP FUNCTION IF EXISTS ts2_page_text() CASCADE;
24 DROP FUNCTION IF EXISTS add_interwiki(TEXT,INT,SMALLINT) CASCADE;
25
26 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
27 CREATE TABLE mwuser ( -- replace reserved word 'user'
28 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
29 user_name TEXT NOT NULL UNIQUE,
30 user_real_name TEXT,
31 user_password TEXT,
32 user_newpassword TEXT,
33 user_newpass_time TIMESTAMPTZ,
34 user_token TEXT,
35 user_email TEXT,
36 user_email_token TEXT,
37 user_email_token_expires TIMESTAMPTZ,
38 user_email_authenticated TIMESTAMPTZ,
39 user_touched TIMESTAMPTZ,
40 user_registration TIMESTAMPTZ,
41 user_editcount INTEGER
42 );
43 CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
44
45 -- Create a dummy user to satisfy fk contraints especially with revisions
46 INSERT INTO mwuser
47 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
48
49 CREATE TABLE user_groups (
50 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
51 ug_group TEXT NOT NULL
52 );
53 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
54
55 CREATE TABLE user_former_groups (
56 ufg_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
57 ufg_group TEXT NOT NULL
58 );
59 CREATE UNIQUE INDEX ufg_user_group ON user_former_groups (ufg_user, ufg_group);
60
61 CREATE TABLE user_newtalk (
62 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
63 user_ip TEXT NULL,
64 user_last_timestamp TIMESTAMPTZ
65 );
66 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
67 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
68
69
70 CREATE SEQUENCE page_page_id_seq;
71 CREATE TABLE page (
72 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
73 page_namespace SMALLINT NOT NULL,
74 page_title TEXT NOT NULL,
75 page_restrictions TEXT,
76 page_counter BIGINT NOT NULL DEFAULT 0,
77 page_is_redirect SMALLINT NOT NULL DEFAULT 0,
78 page_is_new SMALLINT NOT NULL DEFAULT 0,
79 page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(),
80 page_touched TIMESTAMPTZ,
81 page_latest INTEGER NOT NULL, -- FK?
82 page_len INTEGER NOT NULL
83 );
84 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
85 CREATE INDEX page_main_title ON page (page_title text_pattern_ops) WHERE page_namespace = 0;
86 CREATE INDEX page_talk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 1;
87 CREATE INDEX page_user_title ON page (page_title text_pattern_ops) WHERE page_namespace = 2;
88 CREATE INDEX page_utalk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 3;
89 CREATE INDEX page_project_title ON page (page_title text_pattern_ops) WHERE page_namespace = 4;
90 CREATE INDEX page_mediawiki_title ON page (page_title text_pattern_ops) WHERE page_namespace = 8;
91 CREATE INDEX page_random_idx ON page (page_random);
92 CREATE INDEX page_len_idx ON page (page_len);
93
94 CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS
95 $mw$
96 BEGIN
97 DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title;
98 RETURN NULL;
99 END;
100 $mw$;
101
102 CREATE TRIGGER page_deleted AFTER DELETE ON page
103 FOR EACH ROW EXECUTE PROCEDURE page_deleted();
104
105 CREATE SEQUENCE revision_rev_id_seq;
106 CREATE TABLE revision (
107 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('revision_rev_id_seq'),
108 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
109 rev_text_id INTEGER NULL, -- FK
110 rev_comment TEXT,
111 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED,
112 rev_user_text TEXT NOT NULL,
113 rev_timestamp TIMESTAMPTZ NOT NULL,
114 rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
115 rev_deleted SMALLINT NOT NULL DEFAULT 0,
116 rev_len INTEGER NULL,
117 rev_parent_id INTEGER NULL,
118 rev_sha1 TEXT NOT NULL DEFAULT ''
119 );
120 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
121 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
122 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
123 CREATE INDEX rev_user_idx ON revision (rev_user);
124 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
125
126
127 CREATE SEQUENCE text_old_id_seq;
128 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
129 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_seq'),
130 old_text TEXT,
131 old_flags TEXT
132 );
133
134
135 CREATE SEQUENCE page_restrictions_pr_id_seq;
136 CREATE TABLE page_restrictions (
137 pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('page_restrictions_pr_id_seq'),
138 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
139 pr_type TEXT NOT NULL,
140 pr_level TEXT NOT NULL,
141 pr_cascade SMALLINT NOT NULL,
142 pr_user INTEGER NULL,
143 pr_expiry TIMESTAMPTZ NULL
144 );
145 ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
146
147 CREATE TABLE page_props (
148 pp_page INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
149 pp_propname TEXT NOT NULL,
150 pp_value TEXT NOT NULL
151 );
152 ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
153 CREATE INDEX page_props_propname ON page_props (pp_propname);
154
155 CREATE TABLE archive (
156 ar_namespace SMALLINT NOT NULL,
157 ar_title TEXT NOT NULL,
158 ar_text TEXT, -- technically should be bytea, but not used anymore
159 ar_page_id INTEGER NULL,
160 ar_parent_id INTEGER NULL,
161 ar_sha1 TEXT NOT NULL DEFAULT '',
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 ipb_parent_block_id INTEGER NULL REFERENCES ipblocks(ipb_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED
282
283 );
284 CREATE UNIQUE INDEX ipb_address_unique ON ipblocks (ipb_address,ipb_user,ipb_auto,ipb_anon_only);
285 CREATE INDEX ipb_user ON ipblocks (ipb_user);
286 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
287 CREATE INDEX ipb_parent_block_id ON ipblocks (ipb_parent_block_id);
288
289
290 CREATE TABLE image (
291 img_name TEXT NOT NULL PRIMARY KEY,
292 img_size INTEGER NOT NULL,
293 img_width INTEGER NOT NULL,
294 img_height INTEGER NOT NULL,
295 img_metadata BYTEA NOT NULL DEFAULT '',
296 img_bits SMALLINT,
297 img_media_type TEXT,
298 img_major_mime TEXT DEFAULT 'unknown',
299 img_minor_mime TEXT DEFAULT 'unknown',
300 img_description TEXT NOT NULL,
301 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
302 img_user_text TEXT NOT NULL,
303 img_timestamp TIMESTAMPTZ,
304 img_sha1 TEXT NOT NULL DEFAULT ''
305 );
306 CREATE INDEX img_size_idx ON image (img_size);
307 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
308 CREATE INDEX img_sha1 ON image (img_sha1);
309
310 CREATE TABLE oldimage (
311 oi_name TEXT NOT NULL,
312 oi_archive_name TEXT NOT NULL,
313 oi_size INTEGER NOT NULL,
314 oi_width INTEGER NOT NULL,
315 oi_height INTEGER NOT NULL,
316 oi_bits SMALLINT NULL,
317 oi_description TEXT,
318 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
319 oi_user_text TEXT NOT NULL,
320 oi_timestamp TIMESTAMPTZ NULL,
321 oi_metadata BYTEA NOT NULL DEFAULT '',
322 oi_media_type TEXT NULL,
323 oi_major_mime TEXT NULL DEFAULT 'unknown',
324 oi_minor_mime TEXT NULL DEFAULT 'unknown',
325 oi_deleted SMALLINT NOT NULL DEFAULT 0,
326 oi_sha1 TEXT NOT NULL DEFAULT ''
327 );
328 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;
329 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
330 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
331 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
332
333
334 CREATE SEQUENCE filearchive_fa_id_seq;
335 CREATE TABLE filearchive (
336 fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
337 fa_name TEXT NOT NULL,
338 fa_archive_name TEXT,
339 fa_storage_group TEXT,
340 fa_storage_key TEXT,
341 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
342 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
343 fa_deleted_reason TEXT,
344 fa_size INTEGER NOT NULL,
345 fa_width INTEGER NOT NULL,
346 fa_height INTEGER NOT NULL,
347 fa_metadata BYTEA NOT NULL DEFAULT '',
348 fa_bits SMALLINT,
349 fa_media_type TEXT,
350 fa_major_mime TEXT DEFAULT 'unknown',
351 fa_minor_mime TEXT DEFAULT 'unknown',
352 fa_description TEXT NOT NULL,
353 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
354 fa_user_text TEXT NOT NULL,
355 fa_timestamp TIMESTAMPTZ,
356 fa_deleted SMALLINT NOT NULL DEFAULT 0
357 );
358 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
359 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
360 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
361 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
362
363 CREATE SEQUENCE uploadstash_us_id_seq;
364 CREATE TYPE media_type AS ENUM ('UNKNOWN','BITMAP','DRAWING','AUDIO','VIDEO','MULTIMEDIA','OFFICE','TEXT','EXECUTABLE','ARCHIVE');
365
366 CREATE TABLE uploadstash (
367 us_id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('uploadstash_us_id_seq'),
368 us_user INTEGER,
369 us_key TEXT,
370 us_orig_path TEXT,
371 us_path TEXT,
372 us_source_type TEXT,
373 us_timestamp TIMESTAMPTZ,
374 us_status TEXT,
375 us_chunk_inx INTEGER NULL,
376 us_size INTEGER,
377 us_sha1 TEXT,
378 us_mime TEXT,
379 us_media_type media_type DEFAULT NULL,
380 us_image_width INTEGER,
381 us_image_height INTEGER,
382 us_image_bits SMALLINT
383 );
384
385 CREATE INDEX us_user_idx ON uploadstash (us_user);
386 CREATE UNIQUE INDEX us_key_idx ON uploadstash (us_key);
387 CREATE INDEX us_timestamp_idx ON uploadstash (us_timestamp);
388
389
390 CREATE SEQUENCE recentchanges_rc_id_seq;
391 CREATE TABLE recentchanges (
392 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('recentchanges_rc_id_seq'),
393 rc_timestamp TIMESTAMPTZ NOT NULL,
394 rc_cur_time TIMESTAMPTZ NOT NULL,
395 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
396 rc_user_text TEXT NOT NULL,
397 rc_namespace SMALLINT NOT NULL,
398 rc_title TEXT NOT NULL,
399 rc_comment TEXT,
400 rc_minor SMALLINT NOT NULL DEFAULT 0,
401 rc_bot SMALLINT NOT NULL DEFAULT 0,
402 rc_new SMALLINT NOT NULL DEFAULT 0,
403 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
404 rc_this_oldid INTEGER NOT NULL,
405 rc_last_oldid INTEGER NOT NULL,
406 rc_type SMALLINT NOT NULL DEFAULT 0,
407 rc_moved_to_ns SMALLINT,
408 rc_moved_to_title TEXT,
409 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
410 rc_ip CIDR,
411 rc_old_len INTEGER,
412 rc_new_len INTEGER,
413 rc_deleted SMALLINT NOT NULL DEFAULT 0,
414 rc_logid INTEGER NOT NULL DEFAULT 0,
415 rc_log_type TEXT,
416 rc_log_action TEXT,
417 rc_params TEXT
418 );
419 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
420 CREATE INDEX rc_timestamp_bot ON recentchanges (rc_timestamp) WHERE rc_bot = 0;
421 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
422 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
423 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
424 CREATE INDEX rc_ip ON recentchanges (rc_ip);
425
426
427 CREATE TABLE watchlist (
428 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
429 wl_namespace SMALLINT NOT NULL DEFAULT 0,
430 wl_title TEXT NOT NULL,
431 wl_notificationtimestamp TIMESTAMPTZ
432 );
433 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
434 CREATE INDEX wl_user ON watchlist (wl_user);
435
436
437 CREATE TABLE interwiki (
438 iw_prefix TEXT NOT NULL UNIQUE,
439 iw_url TEXT NOT NULL,
440 iw_local SMALLINT NOT NULL,
441 iw_trans SMALLINT NOT NULL DEFAULT 0,
442 iw_api TEXT NOT NULL DEFAULT '',
443 iw_wikiid TEXT NOT NULL DEFAULT ''
444 );
445
446
447 CREATE TABLE querycache (
448 qc_type TEXT NOT NULL,
449 qc_value INTEGER NOT NULL,
450 qc_namespace SMALLINT NOT NULL,
451 qc_title TEXT NOT NULL
452 );
453 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
454
455 CREATE TABLE querycache_info (
456 qci_type TEXT UNIQUE,
457 qci_timestamp TIMESTAMPTZ NULL
458 );
459
460 CREATE TABLE querycachetwo (
461 qcc_type TEXT NOT NULL,
462 qcc_value INTEGER NOT NULL DEFAULT 0,
463 qcc_namespace INTEGER NOT NULL DEFAULT 0,
464 qcc_title TEXT NOT NULL DEFAULT '',
465 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
466 qcc_titletwo TEXT NOT NULL DEFAULT ''
467 );
468 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
469 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
470 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
471
472 CREATE TABLE objectcache (
473 keyname TEXT UNIQUE,
474 value BYTEA NOT NULL DEFAULT '',
475 exptime TIMESTAMPTZ NOT NULL
476 );
477 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
478
479 CREATE TABLE transcache (
480 tc_url TEXT NOT NULL UNIQUE,
481 tc_contents TEXT NOT NULL,
482 tc_time TIMESTAMPTZ NOT NULL
483 );
484
485
486 CREATE SEQUENCE logging_log_id_seq;
487 CREATE TABLE logging (
488 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('logging_log_id_seq'),
489 log_type TEXT NOT NULL,
490 log_action TEXT NOT NULL,
491 log_timestamp TIMESTAMPTZ NOT NULL,
492 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
493 log_namespace SMALLINT NOT NULL,
494 log_title TEXT NOT NULL,
495 log_comment TEXT,
496 log_params TEXT,
497 log_deleted SMALLINT NOT NULL DEFAULT 0,
498 log_user_text TEXT NOT NULL DEFAULT '',
499 log_page INTEGER
500 );
501 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
502 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
503 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
504 CREATE INDEX logging_times ON logging (log_timestamp);
505 CREATE INDEX logging_user_type_time ON logging (log_user, log_type, log_timestamp);
506 CREATE INDEX logging_page_id_time ON logging (log_page, log_timestamp);
507
508 CREATE TABLE log_search (
509 ls_field TEXT NOT NULL,
510 ls_value TEXT NOT NULL,
511 ls_log_id INTEGER NOT NULL DEFAULT 0,
512 PRIMARY KEY (ls_field,ls_value,ls_log_id)
513 );
514 CREATE INDEX ls_log_id ON log_search (ls_log_id);
515
516
517 CREATE SEQUENCE job_job_id_seq;
518 CREATE TABLE job (
519 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
520 job_cmd TEXT NOT NULL,
521 job_namespace SMALLINT NOT NULL,
522 job_title TEXT NOT NULL,
523 job_timestamp TIMESTAMPTZ,
524 job_params TEXT NOT NULL
525 );
526 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
527 CREATE INDEX job_timestamp_idx ON job (job_timestamp);
528
529 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
530 -- Version 8.3 or higher only. Previous versions would need another parmeter for to_tsvector.
531 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
532
533 ALTER TABLE page ADD titlevector tsvector;
534 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
535 $mw$
536 BEGIN
537 IF TG_OP = 'INSERT' THEN
538 NEW.titlevector = to_tsvector(REPLACE(NEW.page_title,'/',' '));
539 ELSIF NEW.page_title != OLD.page_title THEN
540 NEW.titlevector := to_tsvector(REPLACE(NEW.page_title,'/',' '));
541 END IF;
542 RETURN NEW;
543 END;
544 $mw$;
545
546 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
547 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
548
549
550 ALTER TABLE pagecontent ADD textvector tsvector;
551 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
552 $mw$
553 BEGIN
554 IF TG_OP = 'INSERT' THEN
555 NEW.textvector = to_tsvector(NEW.old_text);
556 ELSIF NEW.old_text != OLD.old_text THEN
557 NEW.textvector := to_tsvector(NEW.old_text);
558 END IF;
559 RETURN NEW;
560 END;
561 $mw$;
562
563 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
564 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
565
566 -- These are added by the setup script due to version compatibility issues
567 -- If using 8.1, we switch from "gin" to "gist"
568
569 CREATE INDEX ts2_page_title ON page USING gin(titlevector);
570 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
571
572 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
573 $mw$
574 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
575 SELECT 1;
576 $mw$;
577
578 -- This table is not used unless profiling is turned on
579 CREATE TABLE profiling (
580 pf_count INTEGER NOT NULL DEFAULT 0,
581 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
582 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
583 pf_name TEXT NOT NULL,
584 pf_server TEXT NULL
585 );
586 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
587
588 CREATE TABLE protected_titles (
589 pt_namespace SMALLINT NOT NULL,
590 pt_title TEXT NOT NULL,
591 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
592 pt_reason TEXT NULL,
593 pt_timestamp TIMESTAMPTZ NOT NULL,
594 pt_expiry TIMESTAMPTZ NULL,
595 pt_create_perm TEXT NOT NULL DEFAULT ''
596 );
597 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
598
599
600 CREATE TABLE updatelog (
601 ul_key TEXT NOT NULL PRIMARY KEY,
602 ul_value TEXT
603 );
604
605
606 CREATE SEQUENCE category_cat_id_seq;
607 CREATE TABLE category (
608 cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_cat_id_seq'),
609 cat_title TEXT NOT NULL,
610 cat_pages INTEGER NOT NULL DEFAULT 0,
611 cat_subcats INTEGER NOT NULL DEFAULT 0,
612 cat_files INTEGER NOT NULL DEFAULT 0,
613 cat_hidden SMALLINT NOT NULL DEFAULT 0
614 );
615 CREATE UNIQUE INDEX category_title ON category(cat_title);
616 CREATE INDEX category_pages ON category(cat_pages);
617
618 CREATE TABLE change_tag (
619 ct_rc_id INTEGER NULL,
620 ct_log_id INTEGER NULL,
621 ct_rev_id INTEGER NULL,
622 ct_tag TEXT NOT NULL,
623 ct_params TEXT NULL
624 );
625 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag(ct_rc_id,ct_tag);
626 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag(ct_log_id,ct_tag);
627 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag(ct_rev_id,ct_tag);
628 CREATE INDEX change_tag_tag_id ON change_tag(ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
629
630 CREATE TABLE tag_summary (
631 ts_rc_id INTEGER NULL,
632 ts_log_id INTEGER NULL,
633 ts_rev_id INTEGER NULL,
634 ts_tags TEXT NOT NULL
635 );
636 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary(ts_rc_id);
637 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary(ts_log_id);
638 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary(ts_rev_id);
639
640 CREATE TABLE valid_tag (
641 vt_tag TEXT NOT NULL PRIMARY KEY
642 );
643
644 CREATE TABLE user_properties (
645 up_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
646 up_property TEXT NOT NULL,
647 up_value TEXT
648 );
649 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
650 CREATE INDEX user_properties_property ON user_properties (up_property);
651
652 CREATE TABLE l10n_cache (
653 lc_lang TEXT NOT NULL,
654 lc_key TEXT NOT NULL,
655 lc_value TEXT NOT NULL
656 );
657 CREATE INDEX l10n_cache_lc_lang_key ON l10n_cache (lc_lang, lc_key);
658
659 CREATE TABLE iwlinks (
660 iwl_from INTEGER NOT NULL DEFAULT 0,
661 iwl_prefix TEXT NOT NULL DEFAULT '',
662 iwl_title TEXT NOT NULL DEFAULT ''
663 );
664 CREATE UNIQUE INDEX iwl_from ON iwlinks (iwl_from, iwl_prefix, iwl_title);
665 CREATE UNIQUE INDEX iwl_prefix_title_from ON iwlinks (iwl_prefix, iwl_title, iwl_from);
666
667 CREATE TABLE msg_resource (
668 mr_resource TEXT NOT NULL,
669 mr_lang TEXT NOT NULL,
670 mr_blob TEXT NOT NULL,
671 mr_timestamp TIMESTAMPTZ NOT NULL
672 );
673 CREATE UNIQUE INDEX mr_resource_lang ON msg_resource (mr_resource, mr_lang);
674
675 CREATE TABLE msg_resource_links (
676 mrl_resource TEXT NOT NULL,
677 mrl_message TEXT NOT NULL
678 );
679 CREATE UNIQUE INDEX mrl_message_resource ON msg_resource_links (mrl_message, mrl_resource);
680
681 CREATE TABLE module_deps (
682 md_module TEXT NOT NULL,
683 md_skin TEXT NOT NULL,
684 md_deps TEXT NOT NULL
685 );
686 CREATE UNIQUE INDEX md_module_skin ON module_deps (md_module, md_skin);
687
688 CREATE TABLE config (
689 cf_name TEXT NOT NULL PRIMARY KEY,
690 cf_value TEXT NOT NULL
691 );
692 CREATE INDEX cf_name_value ON config (cf_name, cf_value);