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