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