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