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