Merge "mw.Feedback: If the message is posted remotely, link the title correctly"
[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 ip_changes_ipc_rev_id_seq;
162
163 CREATE TABLE ip_changes (
164 ipc_rev_id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('ip_changes_ipc_rev_id_seq'),
165 ipc_rev_timestamp TIMESTAMPTZ NOT NULL,
166 ipc_hex BYTEA NOT NULL DEFAULT ''
167 );
168
169 CREATE INDEX ipc_rev_timestamp ON ip_changes (ipc_rev_timestamp);
170 CREATE INDEX ipc_hex_time ON ip_changes (ipc_hex,ipc_rev_timestamp);
171
172 CREATE SEQUENCE text_old_id_seq;
173 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
174 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_seq'),
175 old_text TEXT,
176 old_flags TEXT
177 );
178
179
180 CREATE SEQUENCE comment_comment_id_seq;
181 CREATE TABLE comment (
182 comment_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('comment_comment_id_seq'),
183 comment_hash INTEGER NOT NULL,
184 comment_text TEXT NOT NULL,
185 comment_data TEXT
186 );
187 CREATE INDEX comment_hash ON comment (comment_hash);
188
189
190 CREATE SEQUENCE page_restrictions_pr_id_seq;
191 CREATE TABLE page_restrictions (
192 pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('page_restrictions_pr_id_seq'),
193 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
194 pr_type TEXT NOT NULL,
195 pr_level TEXT NOT NULL,
196 pr_cascade SMALLINT NOT NULL,
197 pr_user INTEGER NULL,
198 pr_expiry TIMESTAMPTZ NULL
199 );
200 ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
201
202 CREATE TABLE page_props (
203 pp_page INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
204 pp_propname TEXT NOT NULL,
205 pp_value TEXT NOT NULL,
206 pp_sortkey FLOAT
207 );
208 ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
209 CREATE INDEX page_props_propname ON page_props (pp_propname);
210 CREATE UNIQUE INDEX pp_propname_page ON page_props (pp_propname,pp_page);
211 CREATE INDEX pp_propname_sortkey_page ON page_props (pp_propname, pp_sortkey, pp_page) WHERE (pp_sortkey IS NOT NULL);
212
213 CREATE SEQUENCE archive_ar_id_seq;
214 CREATE TABLE archive (
215 ar_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('archive_ar_id_seq'),
216 ar_namespace SMALLINT NOT NULL,
217 ar_title TEXT NOT NULL,
218 ar_text TEXT, -- technically should be bytea, but not used anymore
219 ar_page_id INTEGER NULL,
220 ar_parent_id INTEGER NULL,
221 ar_sha1 TEXT NOT NULL DEFAULT '',
222 ar_comment TEXT NOT NULL DEFAULT '',
223 ar_comment_id INTEGER NOT NULL DEFAULT 0,
224 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
225 ar_user_text TEXT NOT NULL,
226 ar_timestamp TIMESTAMPTZ NOT NULL,
227 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
228 ar_flags TEXT,
229 ar_rev_id INTEGER,
230 ar_text_id INTEGER,
231 ar_deleted SMALLINT NOT NULL DEFAULT 0,
232 ar_len INTEGER NULL,
233 ar_content_model TEXT,
234 ar_content_format TEXT
235 );
236 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
237 CREATE INDEX archive_user_text ON archive (ar_user_text);
238
239
240 CREATE TABLE slots (
241 slot_revision_id INTEGER NOT NULL,
242 slot_role_id SMALLINT NOT NULL,
243 slot_content_id INTEGER NOT NULL,
244 slot_inherited SMALLINT NOT NULL DEFAULT 0,
245 PRIMARY KEY (slot_revision_id, slot_role_id)
246 );
247
248 CREATE INDEX slot_role_inherited ON slots (slot_revision_id, slot_role_id, slot_inherited);
249
250
251 CREATE SEQUENCE content_content_id_seq;
252 CREATE TABLE content (
253 content_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('content_content_id_seq'),
254 content_size INTEGER NOT NULL,
255 content_sha1 TEXT NOT NULL,
256 content_model SMALLINT NOT NULL,
257 content_address TEXT NOT NULL
258 );
259
260
261 CREATE SEQUENCE slot_roles_role_id_seq;
262 CREATE TABLE slot_roles (
263 role_id SMALLINT NOT NULL PRIMARY KEY DEFAULT nextval('slot_roles_role_id_seq'),
264 role_name TEXT NOT NULL
265 );
266
267 CREATE UNIQUE INDEX role_name ON slot_roles (role_name);
268
269
270 CREATE SEQUENCE content_models_model_id_seq;
271 CREATE TABLE content_models (
272 model_id SMALLINT NOT NULL PRIMARY KEY DEFAULT nextval('content_models_model_id_seq'),
273 model_name TEXT NOT NULL
274 );
275
276 CREATE UNIQUE INDEX model_name ON content_models (model_name);
277
278
279 CREATE TABLE redirect (
280 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
281 rd_namespace SMALLINT NOT NULL,
282 rd_title TEXT NOT NULL,
283 rd_interwiki TEXT NULL,
284 rd_fragment TEXT NULL
285 );
286 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
287
288
289 CREATE TABLE pagelinks (
290 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
291 pl_from_namespace INTEGER NOT NULL DEFAULT 0,
292 pl_namespace SMALLINT NOT NULL,
293 pl_title TEXT NOT NULL
294 );
295 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
296 CREATE INDEX pagelinks_title ON pagelinks (pl_title);
297
298 CREATE TABLE templatelinks (
299 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
300 tl_from_namespace INTEGER NOT NULL DEFAULT 0,
301 tl_namespace SMALLINT NOT NULL,
302 tl_title TEXT NOT NULL
303 );
304 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
305 CREATE INDEX templatelinks_from ON templatelinks (tl_from);
306
307 CREATE TABLE imagelinks (
308 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
309 il_from_namespace INTEGER NOT NULL DEFAULT 0,
310 il_to TEXT NOT NULL
311 );
312 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
313
314 CREATE TABLE categorylinks (
315 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
316 cl_to TEXT NOT NULL,
317 cl_sortkey TEXT NULL,
318 cl_timestamp TIMESTAMPTZ NOT NULL,
319 cl_sortkey_prefix TEXT NOT NULL DEFAULT '',
320 cl_collation TEXT NOT NULL DEFAULT 0,
321 cl_type TEXT NOT NULL DEFAULT 'page'
322 );
323 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
324 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
325
326 CREATE SEQUENCE externallinks_el_id_seq;
327 CREATE TABLE externallinks (
328 el_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('externallinks_el_id_seq'),
329 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
330 el_to TEXT NOT NULL,
331 el_index TEXT NOT NULL,
332 el_index_60 BYTEA NOT NULL DEFAULT ''
333 );
334 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
335 CREATE INDEX externallinks_index ON externallinks (el_index);
336 CREATE INDEX el_index_60 ON externallinks (el_index_60, el_id);
337 CREATE INDEX el_from_index_60 ON externallinks (el_from, el_index_60, el_id);
338
339 CREATE TABLE langlinks (
340 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
341 ll_lang TEXT,
342 ll_title TEXT
343 );
344 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
345 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
346
347
348 CREATE TABLE site_stats (
349 ss_row_id INTEGER NOT NULL PRIMARY KEY DEFAULT 0,
350 ss_total_edits INTEGER DEFAULT 0,
351 ss_good_articles INTEGER DEFAULT 0,
352 ss_total_pages INTEGER DEFAULT -1,
353 ss_users INTEGER DEFAULT -1,
354 ss_active_users INTEGER DEFAULT -1,
355 ss_admins INTEGER DEFAULT -1,
356 ss_images INTEGER DEFAULT 0
357 );
358
359
360 CREATE SEQUENCE ipblocks_ipb_id_seq;
361 CREATE TABLE ipblocks (
362 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_seq'),
363 ipb_address TEXT NULL,
364 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
365 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
366 ipb_by_text TEXT NOT NULL DEFAULT '',
367 ipb_reason TEXT NOT NULL DEFAULT '',
368 ipb_reason_id INTEGER NOT NULL DEFAULT 0,
369 ipb_timestamp TIMESTAMPTZ NOT NULL,
370 ipb_auto SMALLINT NOT NULL DEFAULT 0,
371 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
372 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
373 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
374 ipb_expiry TIMESTAMPTZ NOT NULL,
375 ipb_range_start TEXT,
376 ipb_range_end TEXT,
377 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
378 ipb_block_email SMALLINT NOT NULL DEFAULT 0,
379 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0,
380 ipb_parent_block_id INTEGER NULL REFERENCES ipblocks(ipb_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED
381
382 );
383 CREATE UNIQUE INDEX ipb_address_unique ON ipblocks (ipb_address,ipb_user,ipb_auto,ipb_anon_only);
384 CREATE INDEX ipb_user ON ipblocks (ipb_user);
385 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
386 CREATE INDEX ipb_parent_block_id ON ipblocks (ipb_parent_block_id);
387
388
389 CREATE TABLE image (
390 img_name TEXT NOT NULL PRIMARY KEY,
391 img_size INTEGER NOT NULL,
392 img_width INTEGER NOT NULL,
393 img_height INTEGER NOT NULL,
394 img_metadata BYTEA NOT NULL DEFAULT '',
395 img_bits SMALLINT,
396 img_media_type TEXT,
397 img_major_mime TEXT DEFAULT 'unknown',
398 img_minor_mime TEXT DEFAULT 'unknown',
399 img_description TEXT NOT NULL DEFAULT '',
400 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
401 img_user_text TEXT NOT NULL,
402 img_timestamp TIMESTAMPTZ,
403 img_sha1 TEXT NOT NULL DEFAULT ''
404 );
405 CREATE INDEX img_size_idx ON image (img_size);
406 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
407 CREATE INDEX img_sha1 ON image (img_sha1);
408
409 CREATE TABLE image_comment_temp (
410 imgcomment_name TEXT NOT NULL,
411 imgcomment_description_id INTEGER NOT NULL,
412 PRIMARY KEY (imgcomment_name, imgcomment_description_id)
413 );
414 CREATE UNIQUE INDEX imgcomment_name ON image_comment_temp (imgcomment_name);
415
416 CREATE TABLE oldimage (
417 oi_name TEXT NOT NULL,
418 oi_archive_name TEXT NOT NULL,
419 oi_size INTEGER NOT NULL,
420 oi_width INTEGER NOT NULL,
421 oi_height INTEGER NOT NULL,
422 oi_bits SMALLINT NULL,
423 oi_description TEXT NOT NULL DEFAULT '',
424 oi_description_id INTEGER NOT NULL DEFAULT 0,
425 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
426 oi_user_text TEXT NOT NULL,
427 oi_timestamp TIMESTAMPTZ NULL,
428 oi_metadata BYTEA NOT NULL DEFAULT '',
429 oi_media_type TEXT NULL,
430 oi_major_mime TEXT NULL DEFAULT 'unknown',
431 oi_minor_mime TEXT NULL DEFAULT 'unknown',
432 oi_deleted SMALLINT NOT NULL DEFAULT 0,
433 oi_sha1 TEXT NOT NULL DEFAULT ''
434 );
435 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;
436 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
437 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
438 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
439
440
441 CREATE SEQUENCE filearchive_fa_id_seq;
442 CREATE TABLE filearchive (
443 fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
444 fa_name TEXT NOT NULL,
445 fa_archive_name TEXT,
446 fa_storage_group TEXT,
447 fa_storage_key TEXT,
448 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
449 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
450 fa_deleted_reason TEXT NOT NULL DEFAULT '',
451 fa_deleted_reason_id INTEGER NOT NULL DEFAULT 0,
452 fa_size INTEGER NOT NULL,
453 fa_width INTEGER NOT NULL,
454 fa_height INTEGER NOT NULL,
455 fa_metadata BYTEA NOT NULL DEFAULT '',
456 fa_bits SMALLINT,
457 fa_media_type TEXT,
458 fa_major_mime TEXT DEFAULT 'unknown',
459 fa_minor_mime TEXT DEFAULT 'unknown',
460 fa_description TEXT NOT NULL DEFAULT '',
461 fa_description_id INTEGER NOT NULL DEFAULT 0,
462 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
463 fa_user_text TEXT NOT NULL,
464 fa_timestamp TIMESTAMPTZ,
465 fa_deleted SMALLINT NOT NULL DEFAULT 0,
466 fa_sha1 TEXT NOT NULL DEFAULT ''
467 );
468 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
469 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
470 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
471 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
472 CREATE INDEX fa_sha1 ON filearchive (fa_sha1);
473
474 CREATE SEQUENCE uploadstash_us_id_seq;
475 CREATE TYPE media_type AS ENUM ('UNKNOWN','BITMAP','DRAWING','AUDIO','VIDEO','MULTIMEDIA','OFFICE','TEXT','EXECUTABLE','ARCHIVE','3D');
476
477 CREATE TABLE uploadstash (
478 us_id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('uploadstash_us_id_seq'),
479 us_user INTEGER,
480 us_key TEXT,
481 us_orig_path TEXT,
482 us_path TEXT,
483 us_props BYTEA,
484 us_source_type TEXT,
485 us_timestamp TIMESTAMPTZ,
486 us_status TEXT,
487 us_chunk_inx INTEGER NULL,
488 us_size INTEGER,
489 us_sha1 TEXT,
490 us_mime TEXT,
491 us_media_type media_type DEFAULT NULL,
492 us_image_width INTEGER,
493 us_image_height INTEGER,
494 us_image_bits SMALLINT
495 );
496
497 CREATE INDEX us_user_idx ON uploadstash (us_user);
498 CREATE UNIQUE INDEX us_key_idx ON uploadstash (us_key);
499 CREATE INDEX us_timestamp_idx ON uploadstash (us_timestamp);
500
501
502 CREATE SEQUENCE recentchanges_rc_id_seq;
503 CREATE TABLE recentchanges (
504 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('recentchanges_rc_id_seq'),
505 rc_timestamp TIMESTAMPTZ NOT NULL,
506 rc_cur_time TIMESTAMPTZ NULL,
507 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
508 rc_user_text TEXT NOT NULL,
509 rc_namespace SMALLINT NOT NULL,
510 rc_title TEXT NOT NULL,
511 rc_comment TEXT NOT NULL DEFAULT '',
512 rc_comment_id INTEGER NOT NULL DEFAULT 0,
513 rc_minor SMALLINT NOT NULL DEFAULT 0,
514 rc_bot SMALLINT NOT NULL DEFAULT 0,
515 rc_new SMALLINT NOT NULL DEFAULT 0,
516 rc_cur_id INTEGER NULL,
517 rc_this_oldid INTEGER NOT NULL,
518 rc_last_oldid INTEGER NOT NULL,
519 rc_type SMALLINT NOT NULL DEFAULT 0,
520 rc_source TEXT NOT NULL,
521 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
522 rc_ip CIDR,
523 rc_old_len INTEGER,
524 rc_new_len INTEGER,
525 rc_deleted SMALLINT NOT NULL DEFAULT 0,
526 rc_logid INTEGER NOT NULL DEFAULT 0,
527 rc_log_type TEXT,
528 rc_log_action TEXT,
529 rc_params TEXT
530 );
531 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
532 CREATE INDEX rc_timestamp_bot ON recentchanges (rc_timestamp) WHERE rc_bot = 0;
533 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
534 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
535 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
536 CREATE INDEX rc_ip ON recentchanges (rc_ip);
537 CREATE INDEX rc_name_type_patrolled_timestamp ON recentchanges (rc_namespace, rc_type, rc_patrolled, rc_timestamp);
538
539
540 CREATE SEQUENCE watchlist_wl_id_seq;
541 CREATE TABLE watchlist (
542 wl_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('watchlist_wl_id_seq'),
543 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
544 wl_namespace SMALLINT NOT NULL DEFAULT 0,
545 wl_title TEXT NOT NULL,
546 wl_notificationtimestamp TIMESTAMPTZ
547 );
548 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
549 CREATE INDEX wl_user ON watchlist (wl_user);
550 CREATE INDEX wl_user_notificationtimestamp ON watchlist (wl_user, wl_notificationtimestamp);
551
552
553 CREATE TABLE interwiki (
554 iw_prefix TEXT NOT NULL UNIQUE,
555 iw_url TEXT NOT NULL,
556 iw_local SMALLINT NOT NULL,
557 iw_trans SMALLINT NOT NULL DEFAULT 0,
558 iw_api TEXT NOT NULL DEFAULT '',
559 iw_wikiid TEXT NOT NULL DEFAULT ''
560 );
561
562
563 CREATE TABLE querycache (
564 qc_type TEXT NOT NULL,
565 qc_value INTEGER NOT NULL,
566 qc_namespace SMALLINT NOT NULL,
567 qc_title TEXT NOT NULL
568 );
569 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
570
571 CREATE TABLE querycache_info (
572 qci_type TEXT UNIQUE,
573 qci_timestamp TIMESTAMPTZ NULL
574 );
575
576 CREATE TABLE querycachetwo (
577 qcc_type TEXT NOT NULL,
578 qcc_value INTEGER NOT NULL DEFAULT 0,
579 qcc_namespace INTEGER NOT NULL DEFAULT 0,
580 qcc_title TEXT NOT NULL DEFAULT '',
581 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
582 qcc_titletwo TEXT NOT NULL DEFAULT ''
583 );
584 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
585 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
586 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
587
588 CREATE TABLE objectcache (
589 keyname TEXT UNIQUE,
590 value BYTEA NOT NULL DEFAULT '',
591 exptime TIMESTAMPTZ NOT NULL
592 );
593 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
594
595 CREATE TABLE transcache (
596 tc_url TEXT NOT NULL UNIQUE,
597 tc_contents TEXT NOT NULL,
598 tc_time TIMESTAMPTZ NOT NULL
599 );
600
601
602 CREATE SEQUENCE logging_log_id_seq;
603 CREATE TABLE logging (
604 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('logging_log_id_seq'),
605 log_type TEXT NOT NULL,
606 log_action TEXT NOT NULL,
607 log_timestamp TIMESTAMPTZ NOT NULL,
608 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
609 log_namespace SMALLINT NOT NULL,
610 log_title TEXT NOT NULL,
611 log_comment TEXT NOT NULL DEFAULT '',
612 log_comment_id INTEGER NOT NULL DEFAULT 0,
613 log_params TEXT,
614 log_deleted SMALLINT NOT NULL DEFAULT 0,
615 log_user_text TEXT NOT NULL DEFAULT '',
616 log_page INTEGER
617 );
618 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
619 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
620 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
621 CREATE INDEX logging_times ON logging (log_timestamp);
622 CREATE INDEX logging_user_type_time ON logging (log_user, log_type, log_timestamp);
623 CREATE INDEX logging_page_id_time ON logging (log_page, log_timestamp);
624 CREATE INDEX logging_user_text_type_time ON logging (log_user_text, log_type, log_timestamp);
625 CREATE INDEX logging_user_text_time ON logging (log_user_text, log_timestamp);
626
627 CREATE TABLE log_search (
628 ls_field TEXT NOT NULL,
629 ls_value TEXT NOT NULL,
630 ls_log_id INTEGER NOT NULL DEFAULT 0,
631 PRIMARY KEY (ls_field,ls_value,ls_log_id)
632 );
633 CREATE INDEX ls_log_id ON log_search (ls_log_id);
634
635
636 CREATE SEQUENCE job_job_id_seq;
637 CREATE TABLE job (
638 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
639 job_cmd TEXT NOT NULL,
640 job_namespace SMALLINT NOT NULL,
641 job_title TEXT NOT NULL,
642 job_timestamp TIMESTAMPTZ,
643 job_params TEXT NOT NULL,
644 job_random INTEGER NOT NULL DEFAULT 0,
645 job_attempts INTEGER NOT NULL DEFAULT 0,
646 job_token TEXT NOT NULL DEFAULT '',
647 job_token_timestamp TIMESTAMPTZ,
648 job_sha1 TEXT NOT NULL DEFAULT ''
649 );
650 CREATE INDEX job_sha1 ON job (job_sha1);
651 CREATE INDEX job_cmd_token ON job (job_cmd, job_token, job_random);
652 CREATE INDEX job_cmd_token_id ON job (job_cmd, job_token, job_id);
653 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
654 CREATE INDEX job_timestamp_idx ON job (job_timestamp);
655
656 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
657 -- Version 8.3 or higher only. Previous versions would need another parmeter for to_tsvector.
658 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
659
660 ALTER TABLE page ADD titlevector tsvector;
661 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
662 $mw$
663 BEGIN
664 IF TG_OP = 'INSERT' THEN
665 NEW.titlevector = to_tsvector(REPLACE(NEW.page_title,'/',' '));
666 ELSIF NEW.page_title != OLD.page_title THEN
667 NEW.titlevector := to_tsvector(REPLACE(NEW.page_title,'/',' '));
668 END IF;
669 RETURN NEW;
670 END;
671 $mw$;
672
673 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
674 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
675
676
677 ALTER TABLE pagecontent ADD textvector tsvector;
678 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
679 $mw$
680 BEGIN
681 IF TG_OP = 'INSERT' THEN
682 NEW.textvector = to_tsvector(NEW.old_text);
683 ELSIF NEW.old_text != OLD.old_text THEN
684 NEW.textvector := to_tsvector(NEW.old_text);
685 END IF;
686 RETURN NEW;
687 END;
688 $mw$;
689
690 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
691 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
692
693 -- These are added by the setup script due to version compatibility issues
694 -- If using 8.1, we switch from "gin" to "gist"
695
696 CREATE INDEX ts2_page_title ON page USING gin(titlevector);
697 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
698
699 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
700 $mw$
701 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
702 SELECT 1;
703 $mw$;
704
705 -- This table is not used unless profiling is turned on
706 CREATE TABLE profiling (
707 pf_count INTEGER NOT NULL DEFAULT 0,
708 pf_time FLOAT NOT NULL DEFAULT 0,
709 pf_memory FLOAT NOT NULL DEFAULT 0,
710 pf_name TEXT NOT NULL,
711 pf_server TEXT NULL
712 );
713 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
714
715 CREATE TABLE protected_titles (
716 pt_namespace SMALLINT NOT NULL,
717 pt_title TEXT NOT NULL,
718 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
719 pt_reason TEXT NOT NULL DEFAULT '',
720 pt_reason_id INTEGER NOT NULL DEFAULT 0,
721 pt_timestamp TIMESTAMPTZ NOT NULL,
722 pt_expiry TIMESTAMPTZ NULL,
723 pt_create_perm TEXT NOT NULL DEFAULT ''
724 );
725 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
726
727
728 CREATE TABLE updatelog (
729 ul_key TEXT NOT NULL PRIMARY KEY,
730 ul_value TEXT
731 );
732
733
734 CREATE SEQUENCE category_cat_id_seq;
735 CREATE TABLE category (
736 cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_cat_id_seq'),
737 cat_title TEXT NOT NULL,
738 cat_pages INTEGER NOT NULL DEFAULT 0,
739 cat_subcats INTEGER NOT NULL DEFAULT 0,
740 cat_files INTEGER NOT NULL DEFAULT 0,
741 cat_hidden SMALLINT NOT NULL DEFAULT 0
742 );
743 CREATE UNIQUE INDEX category_title ON category(cat_title);
744 CREATE INDEX category_pages ON category(cat_pages);
745
746 CREATE SEQUENCE change_tag_ct_id_seq;
747 CREATE TABLE change_tag (
748 ct_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('change_tag_ct_id_seq'),
749 ct_rc_id INTEGER NULL,
750 ct_log_id INTEGER NULL,
751 ct_rev_id INTEGER NULL,
752 ct_tag TEXT NOT NULL,
753 ct_params TEXT NULL
754 );
755 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag(ct_rc_id,ct_tag);
756 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag(ct_log_id,ct_tag);
757 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag(ct_rev_id,ct_tag);
758 CREATE INDEX change_tag_tag_id ON change_tag(ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
759
760 CREATE SEQUENCE tag_summary_ts_id_seq;
761 CREATE TABLE tag_summary (
762 ts_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('tag_summary_ts_id_seq'),
763 ts_rc_id INTEGER NULL,
764 ts_log_id INTEGER NULL,
765 ts_rev_id INTEGER NULL,
766 ts_tags TEXT NOT NULL
767 );
768 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary(ts_rc_id);
769 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary(ts_log_id);
770 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary(ts_rev_id);
771
772 CREATE TABLE valid_tag (
773 vt_tag TEXT NOT NULL PRIMARY KEY
774 );
775
776 CREATE TABLE user_properties (
777 up_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
778 up_property TEXT NOT NULL,
779 up_value TEXT
780 );
781 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
782 CREATE INDEX user_properties_property ON user_properties (up_property);
783
784 CREATE TABLE l10n_cache (
785 lc_lang TEXT NOT NULL,
786 lc_key TEXT NOT NULL,
787 lc_value BYTEA NOT NULL
788 );
789 CREATE INDEX l10n_cache_lc_lang_key ON l10n_cache (lc_lang, lc_key);
790
791 CREATE TABLE iwlinks (
792 iwl_from INTEGER NOT NULL DEFAULT 0,
793 iwl_prefix TEXT NOT NULL DEFAULT '',
794 iwl_title TEXT NOT NULL DEFAULT ''
795 );
796 CREATE UNIQUE INDEX iwl_from ON iwlinks (iwl_from, iwl_prefix, iwl_title);
797 CREATE UNIQUE INDEX iwl_prefix_title_from ON iwlinks (iwl_prefix, iwl_title, iwl_from);
798 CREATE UNIQUE INDEX iwl_prefix_from_title ON iwlinks (iwl_prefix, iwl_from, iwl_title);
799
800 CREATE TABLE module_deps (
801 md_module TEXT NOT NULL,
802 md_skin TEXT NOT NULL,
803 md_deps TEXT NOT NULL
804 );
805 CREATE UNIQUE INDEX md_module_skin ON module_deps (md_module, md_skin);
806
807 CREATE SEQUENCE sites_site_id_seq;
808 CREATE TABLE sites (
809 site_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('sites_site_id_seq'),
810 site_global_key TEXT NOT NULL,
811 site_type TEXT NOT NULL,
812 site_group TEXT NOT NULL,
813 site_source TEXT NOT NULL,
814 site_language TEXT NOT NULL,
815 site_protocol TEXT NOT NULL,
816 site_domain TEXT NOT NULL,
817 site_data TEXT NOT NULL,
818 site_forward SMALLINT NOT NULL,
819 site_config TEXT NOT NULL
820 );
821 CREATE UNIQUE INDEX site_global_key ON sites (site_global_key);
822 CREATE INDEX site_type ON sites (site_type);
823 CREATE INDEX site_group ON sites (site_group);
824 CREATE INDEX site_source ON sites (site_source);
825 CREATE INDEX site_language ON sites (site_language);
826 CREATE INDEX site_protocol ON sites (site_protocol);
827 CREATE INDEX site_domain ON sites (site_domain);
828 CREATE INDEX site_forward ON sites (site_forward);
829
830 CREATE TABLE site_identifiers (
831 si_site INTEGER NOT NULL,
832 si_type TEXT NOT NULL,
833 si_key TEXT NOT NULL
834 );
835 CREATE UNIQUE INDEX si_type_key ON site_identifiers (si_type, si_key);
836 CREATE INDEX si_site ON site_identifiers (si_site);
837 CREATE INDEX si_key ON site_identifiers (si_key);