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