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