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