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