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