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