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