* Fixed the default for recentchanges.rc_*_len to NULL on postgre as it should be
[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 -- We can't use SERIAL everywhere: the sequence names are hard-coded into the PHP
8 -- TODO: Change CHAR to BOOL
9
10 BEGIN;
11 SET client_min_messages = 'ERROR';
12
13 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
14 CREATE TABLE mwuser ( -- replace reserved word 'user'
15 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
16 user_name TEXT NOT NULL UNIQUE,
17 user_real_name TEXT,
18 user_password TEXT,
19 user_newpassword TEXT,
20 user_newpass_time TIMESTAMPTZ,
21 user_token CHAR(32),
22 user_email TEXT,
23 user_email_token CHAR(32),
24 user_email_token_expires TIMESTAMPTZ,
25 user_email_authenticated TIMESTAMPTZ,
26 user_options TEXT,
27 user_touched TIMESTAMPTZ,
28 user_registration TIMESTAMPTZ,
29 user_editcount INTEGER
30 );
31 CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
32
33 -- Create a dummy user to satisfy fk contraints especially with revisions
34 INSERT INTO mwuser
35 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
36
37 CREATE TABLE user_groups (
38 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
39 ug_group TEXT NOT NULL
40 );
41 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
42
43 CREATE TABLE user_newtalk (
44 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
45 user_ip CIDR NULL
46 );
47 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
48 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
49
50
51 CREATE SEQUENCE page_page_id_seq;
52 CREATE TABLE page (
53 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
54 page_namespace SMALLINT NOT NULL,
55 page_title TEXT NOT NULL,
56 page_restrictions TEXT,
57 page_counter BIGINT NOT NULL DEFAULT 0,
58 page_is_redirect CHAR NOT NULL DEFAULT 0,
59 page_is_new CHAR NOT NULL DEFAULT 0,
60 page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(),
61 page_touched TIMESTAMPTZ,
62 page_latest INTEGER NOT NULL, -- FK?
63 page_len INTEGER NOT NULL
64 );
65 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
66 CREATE INDEX page_main_title ON page (page_title) WHERE page_namespace = 0;
67 CREATE INDEX page_talk_title ON page (page_title) WHERE page_namespace = 1;
68 CREATE INDEX page_user_title ON page (page_title) WHERE page_namespace = 2;
69 CREATE INDEX page_utalk_title ON page (page_title) WHERE page_namespace = 3;
70 CREATE INDEX page_project_title ON page (page_title) WHERE page_namespace = 4;
71 CREATE INDEX page_random_idx ON page (page_random);
72 CREATE INDEX page_len_idx ON page (page_len);
73
74 CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS
75 $mw$
76 BEGIN
77 DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title;
78 RETURN NULL;
79 END;
80 $mw$;
81
82 CREATE TRIGGER page_deleted AFTER DELETE ON page
83 FOR EACH ROW EXECUTE PROCEDURE page_deleted();
84
85 CREATE SEQUENCE rev_rev_id_val;
86 CREATE TABLE revision (
87 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('rev_rev_id_val'),
88 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
89 rev_text_id INTEGER NULL, -- FK
90 rev_comment TEXT,
91 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT,
92 rev_user_text TEXT NOT NULL,
93 rev_timestamp TIMESTAMPTZ NOT NULL,
94 rev_minor_edit CHAR NOT NULL DEFAULT '0',
95 rev_deleted CHAR NOT NULL DEFAULT '0'
96 );
97 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
98 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
99 CREATE INDEX rev_user_idx ON revision (rev_user);
100 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
101
102
103 CREATE SEQUENCE text_old_id_val;
104 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
105 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_val'),
106 old_text TEXT,
107 old_flags TEXT
108 );
109
110
111 CREATE TABLE archive2 (
112 ar_namespace SMALLINT NOT NULL,
113 ar_title TEXT NOT NULL,
114 ar_text TEXT,
115 ar_comment TEXT,
116 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
117 ar_user_text TEXT NOT NULL,
118 ar_timestamp TIMESTAMPTZ NOT NULL,
119 ar_minor_edit CHAR NOT NULL DEFAULT '0',
120 ar_flags TEXT,
121 ar_rev_id INTEGER,
122 ar_text_id INTEGER
123 );
124 CREATE INDEX archive_name_title_timestamp ON archive2 (ar_namespace,ar_title,ar_timestamp);
125
126 -- This is the easiest way to work around the char(15) timestamp hack without modifying PHP code
127 CREATE VIEW archive AS
128 SELECT
129 ar_namespace, ar_title, ar_text, ar_comment, ar_user, ar_user_text,
130 ar_minor_edit, ar_flags, ar_rev_id, ar_text_id,
131 TO_CHAR(ar_timestamp, 'YYYYMMDDHH24MISS') AS ar_timestamp
132 FROM archive2;
133
134 CREATE RULE archive_insert AS ON INSERT TO archive
135 DO INSTEAD INSERT INTO archive2 VALUES (
136 NEW.ar_namespace, NEW.ar_title, NEW.ar_text, NEW.ar_comment, NEW.ar_user, NEW.ar_user_text,
137 TO_DATE(NEW.ar_timestamp, 'YYYYMMDDHH24MISS'),
138 NEW.ar_minor_edit, NEW.ar_flags, NEW.ar_rev_id, NEW.ar_text_id
139 );
140
141
142 CREATE TABLE redirect (
143 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
144 rd_namespace SMALLINT NOT NULL,
145 rd_title TEXT NOT NULL
146 );
147 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
148
149
150 CREATE TABLE pagelinks (
151 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
152 pl_namespace SMALLINT NOT NULL,
153 pl_title TEXT NOT NULL
154 );
155 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
156
157 CREATE TABLE templatelinks (
158 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
159 tl_namespace TEXT NOT NULL,
160 tl_title TEXT NOT NULL
161 );
162 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
163
164 CREATE TABLE imagelinks (
165 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
166 il_to TEXT NOT NULL
167 );
168 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
169
170 CREATE TABLE categorylinks (
171 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
172 cl_to TEXT NOT NULL,
173 cl_sortkey TEXT,
174 cl_timestamp TIMESTAMPTZ NOT NULL
175 );
176 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
177 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey);
178
179 CREATE TABLE externallinks (
180 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
181 el_to TEXT NOT NULL,
182 el_index TEXT NOT NULL
183 );
184 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
185 CREATE INDEX externallinks_index ON externallinks (el_index);
186
187 CREATE TABLE langlinks (
188 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
189 ll_lang TEXT,
190 ll_title TEXT
191 );
192 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
193 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
194
195
196 CREATE TABLE site_stats (
197 ss_row_id INTEGER NOT NULL UNIQUE,
198 ss_total_views INTEGER DEFAULT 0,
199 ss_total_edits INTEGER DEFAULT 0,
200 ss_good_articles INTEGER DEFAULT 0,
201 ss_total_pages INTEGER DEFAULT -1,
202 ss_users INTEGER DEFAULT -1,
203 ss_admins INTEGER DEFAULT -1,
204 ss_images INTEGER DEFAULT 0
205 );
206
207 CREATE TABLE hitcounter (
208 hc_id BIGINT NOT NULL
209 );
210
211
212 CREATE SEQUENCE ipblocks_ipb_id_val;
213 CREATE TABLE ipblocks (
214 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
215 ipb_address TEXT NULL,
216 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
217 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
218 ipb_reason TEXT NOT NULL,
219 ipb_timestamp TIMESTAMPTZ NOT NULL,
220 ipb_auto CHAR NOT NULL DEFAULT '0',
221 ipb_anon_only CHAR NOT NULL DEFAULT '0',
222 ipb_create_account CHAR NOT NULL DEFAULT '1',
223 ipb_enable_autoblock CHAR NOT NULL DEFAULT '1',
224 ipb_expiry TIMESTAMPTZ NOT NULL,
225 ipb_range_start TEXT,
226 ipb_range_end TEXT
227 );
228 CREATE INDEX ipb_address ON ipblocks (ipb_address);
229 CREATE INDEX ipb_user ON ipblocks (ipb_user);
230 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
231
232
233 CREATE TABLE image (
234 img_name TEXT NOT NULL PRIMARY KEY,
235 img_size INTEGER NOT NULL,
236 img_width INTEGER NOT NULL,
237 img_height INTEGER NOT NULL,
238 img_metadata TEXT,
239 img_bits SMALLINT,
240 img_media_type TEXT,
241 img_major_mime TEXT DEFAULT 'unknown',
242 img_minor_mime TEXT DEFAULT 'unknown',
243 img_description TEXT NOT NULL,
244 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
245 img_user_text TEXT NOT NULL,
246 img_timestamp TIMESTAMPTZ
247 );
248 CREATE INDEX img_size_idx ON image (img_size);
249 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
250
251 CREATE TABLE oldimage (
252 oi_name TEXT NOT NULL REFERENCES image(img_name),
253 oi_archive_name TEXT NOT NULL,
254 oi_size INTEGER NOT NULL,
255 oi_width INTEGER NOT NULL,
256 oi_height INTEGER NOT NULL,
257 oi_bits SMALLINT NOT NULL,
258 oi_description TEXT,
259 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
260 oi_user_text TEXT NOT NULL,
261 oi_timestamp TIMESTAMPTZ NOT NULL
262 );
263 CREATE INDEX oi_name ON oldimage (oi_name);
264
265
266 CREATE TABLE filearchive (
267 fa_id SERIAL NOT NULL PRIMARY KEY,
268 fa_name TEXT NOT NULL,
269 fa_archive_name TEXT,
270 fa_storage_group VARCHAR(16),
271 fa_storage_key CHAR(64),
272 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
273 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
274 fa_deleted_reason TEXT,
275 fa_size SMALLINT NOT NULL,
276 fa_width SMALLINT NOT NULL,
277 fa_height SMALLINT NOT NULL,
278 fa_metadata TEXT,
279 fa_bits SMALLINT,
280 fa_media_type TEXT,
281 fa_major_mime TEXT DEFAULT 'unknown',
282 fa_minor_mime TEXT DEFAULT 'unknown',
283 fa_description TEXT NOT NULL,
284 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
285 fa_user_text TEXT NOT NULL,
286 fa_timestamp TIMESTAMPTZ
287 );
288 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
289 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
290 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
291 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
292
293
294 CREATE SEQUENCE rc_rc_id_seq;
295 CREATE TABLE recentchanges (
296 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
297 rc_timestamp TIMESTAMPTZ NOT NULL,
298 rc_cur_time TIMESTAMPTZ NOT NULL,
299 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
300 rc_user_text TEXT NOT NULL,
301 rc_namespace SMALLINT NOT NULL,
302 rc_title TEXT NOT NULL,
303 rc_comment TEXT,
304 rc_minor CHAR NOT NULL DEFAULT '0',
305 rc_bot CHAR NOT NULL DEFAULT '0',
306 rc_new CHAR NOT NULL DEFAULT '0',
307 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
308 rc_this_oldid INTEGER NOT NULL,
309 rc_last_oldid INTEGER NOT NULL,
310 rc_type CHAR NOT NULL DEFAULT '0',
311 rc_moved_to_ns SMALLINT,
312 rc_moved_to_title TEXT,
313 rc_patrolled CHAR NOT NULL DEFAULT '0',
314 rc_ip CIDR,
315 rc_old_len INTEGER,
316 rc_new_len INTEGER
317 );
318 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
319 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
320 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
321 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
322 CREATE INDEX rc_ip ON recentchanges (rc_ip);
323
324
325 CREATE TABLE watchlist (
326 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
327 wl_namespace SMALLINT NOT NULL DEFAULT 0,
328 wl_title TEXT NOT NULL,
329 wl_notificationtimestamp TIMESTAMPTZ
330 );
331 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
332
333
334 CREATE TABLE math (
335 math_inputhash TEXT NOT NULL UNIQUE,
336 math_outputhash TEXT NOT NULL,
337 math_html_conservativeness SMALLINT NOT NULL,
338 math_html TEXT,
339 math_mathml TEXT
340 );
341
342
343 CREATE TABLE interwiki (
344 iw_prefix TEXT NOT NULL UNIQUE,
345 iw_url TEXT NOT NULL,
346 iw_local CHAR NOT NULL,
347 iw_trans CHAR NOT NULL DEFAULT '0'
348 );
349
350
351 CREATE TABLE querycache (
352 qc_type TEXT NOT NULL,
353 qc_value SMALLINT NOT NULL,
354 qc_namespace SMALLINT NOT NULL,
355 qc_title TEXT NOT NULL
356 );
357 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
358
359 CREATE TABLE querycache_info (
360 qci_type TEXT UNIQUE,
361 qci_timestamp TIMESTAMPTZ NULL
362 );
363
364 CREATE TABLE querycachetwo (
365 qcc_type TEXT NOT NULL,
366 qcc_value SMALLINT NOT NULL DEFAULT 0,
367 qcc_namespace INTEGER NOT NULL DEFAULT 0,
368 qcc_title TEXT NOT NULL DEFAULT '',
369 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
370 qcc_titletwo TEXT NOT NULL DEFAULT ''
371 );
372 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
373 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
374 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
375
376
377 CREATE TABLE objectcache (
378 keyname CHAR(255) UNIQUE,
379 value BYTEA NOT NULL DEFAULT '',
380 exptime TIMESTAMPTZ NOT NULL
381 );
382 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
383
384 CREATE TABLE transcache (
385 tc_url TEXT NOT NULL UNIQUE,
386 tc_contents TEXT NOT NULL,
387 tc_time TIMESTAMPTZ NOT NULL
388 );
389
390
391 CREATE TABLE logging (
392 log_type TEXT NOT NULL,
393 log_action TEXT NOT NULL,
394 log_timestamp TIMESTAMPTZ NOT NULL,
395 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
396 log_namespace SMALLINT NOT NULL,
397 log_title TEXT NOT NULL,
398 log_comment TEXT,
399 log_params TEXT
400 );
401 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
402 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
403 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
404
405
406 CREATE TABLE trackbacks (
407 tb_id SERIAL NOT NULL PRIMARY KEY,
408 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
409 tb_title TEXT NOT NULL,
410 tb_url TEXT NOT NULL,
411 tb_ex TEXT,
412 tb_name TEXT
413 );
414 CREATE INDEX trackback_page ON trackbacks (tb_page);
415
416
417 CREATE SEQUENCE job_job_id_seq;
418 CREATE TABLE job (
419 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
420 job_cmd TEXT NOT NULL,
421 job_namespace SMALLINT NOT NULL,
422 job_title TEXT NOT NULL,
423 job_params TEXT NOT NULL
424 );
425 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
426
427 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
428
429 ALTER TABLE page ADD titlevector tsvector;
430 CREATE INDEX ts2_page_title ON page USING gist(titlevector);
431 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
432 $mw$
433 BEGIN
434 IF TG_OP = 'INSERT' THEN
435 NEW.titlevector = to_tsvector('default',NEW.page_title);
436 ELSIF NEW.page_title != OLD.page_title THEN
437 NEW.titlevector := to_tsvector('default',NEW.page_title);
438 END IF;
439 RETURN NEW;
440 END;
441 $mw$;
442
443 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
444 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
445
446
447 ALTER TABLE pagecontent ADD textvector tsvector;
448 CREATE INDEX ts2_page_text ON pagecontent USING gist(textvector);
449 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
450 $mw$
451 BEGIN
452 IF TG_OP = 'INSERT' THEN
453 NEW.textvector = to_tsvector('default',NEW.old_text);
454 ELSIF NEW.old_text != OLD.old_text THEN
455 NEW.textvector := to_tsvector('default',NEW.old_text);
456 END IF;
457 RETURN NEW;
458 END;
459 $mw$;
460
461 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
462 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
463
464 CREATE FUNCTION add_interwiki (TEXT,INT,CHAR) RETURNS INT LANGUAGE SQL AS
465 $mw$
466 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
467 SELECT 1;
468 $mw$;
469
470 -- This table is not used unless profiling is turned on
471 CREATE TABLE profiling (
472 pf_count INTEGER NOT NULL DEFAULT 0,
473 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
474 pf_name TEXT NOT NULL,
475 pf_server TEXT NULL
476 );
477 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
478
479
480 CREATE TABLE mediawiki_version (
481 type TEXT NOT NULL,
482 mw_version TEXT NOT NULL,
483 notes TEXT NULL,
484
485 pg_version TEXT NULL,
486 pg_dbname TEXT NULL,
487 pg_user TEXT NULL,
488 pg_port TEXT NULL,
489 mw_schema TEXT NULL,
490 ts2_schema TEXT NULL,
491 ctype TEXT NULL,
492
493 sql_version TEXT NULL,
494 sql_date TEXT NULL,
495 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
496 );
497
498 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
499 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
500
501
502 COMMIT;