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