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