Deletion-related housekeeping.
[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" VALUES
33 (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 archive (
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 archive (ar_namespace,ar_title,ar_timestamp);
129
130
131 CREATE TABLE pagelinks (
132 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
133 pl_namespace SMALLINT NOT NULL,
134 pl_title TEXT NOT NULL
135 );
136 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_namespace,pl_title,pl_from);
137
138 CREATE TABLE templatelinks (
139 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
140 tl_namespace TEXT NOT NULL,
141 tl_title TEXT NOT NULL
142 );
143 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
144
145 CREATE TABLE imagelinks (
146 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
147 il_to TEXT NOT NULL
148 );
149 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
150
151 CREATE TABLE categorylinks (
152 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
153 cl_to TEXT NOT NULL,
154 cl_sortkey TEXT,
155 cl_timestamp TIMESTAMPTZ NOT NULL
156 );
157 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
158 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey);
159
160 CREATE TABLE externallinks (
161 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
162 el_to TEXT NOT NULL,
163 el_index TEXT NOT NULL
164 );
165 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
166 CREATE INDEX externallinks_index ON externallinks (el_index);
167
168 CREATE TABLE langlinks (
169 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
170 ll_lang TEXT,
171 ll_title TEXT
172 );
173 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
174 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
175
176
177 CREATE TABLE site_stats (
178 ss_row_id INTEGER NOT NULL UNIQUE,
179 ss_total_views INTEGER DEFAULT 0,
180 ss_total_edits INTEGER DEFAULT 0,
181 ss_good_articles INTEGER DEFAULT 0,
182 ss_total_pages INTEGER DEFAULT -1,
183 ss_users INTEGER DEFAULT -1,
184 ss_admins INTEGER DEFAULT -1,
185 ss_images INTEGER DEFAULT 0
186 );
187
188 CREATE TABLE hitcounter (
189 hc_id BIGINT NOT NULL
190 );
191
192
193 CREATE SEQUENCE ipblocks_ipb_id_val;
194 CREATE TABLE ipblocks (
195 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
196 ipb_address CIDR NULL,
197 ipb_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
198 ipb_by INTEGER NOT NULL REFERENCES "user"(user_id) ON DELETE CASCADE,
199 ipb_reason TEXT NOT NULL,
200 ipb_timestamp TIMESTAMPTZ NOT NULL,
201 ipb_auto CHAR NOT NULL DEFAULT '0',
202 ipb_anon_only CHAR NOT NULL DEFAULT '0',
203 ipb_create_account CHAR NOT NULL DEFAULT '1',
204 ipb_expiry TIMESTAMPTZ NOT NULL,
205 ipb_range_start TEXT,
206 ipb_range_end TEXT
207 );
208 CREATE INDEX ipb_address ON ipblocks (ipb_address);
209 CREATE INDEX ipb_user ON ipblocks (ipb_user);
210 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
211
212
213 CREATE TABLE image (
214 img_name TEXT NOT NULL PRIMARY KEY,
215 img_size INTEGER NOT NULL,
216 img_width INTEGER NOT NULL,
217 img_height INTEGER NOT NULL,
218 img_metadata TEXT,
219 img_bits SMALLINT,
220 img_media_type TEXT,
221 img_major_mime TEXT DEFAULT 'unknown',
222 img_minor_mime TEXT DEFAULT 'unknown',
223 img_description TEXT NOT NULL,
224 img_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
225 img_user_text TEXT NOT NULL,
226 img_timestamp TIMESTAMPTZ
227 );
228 CREATE INDEX img_size_idx ON image (img_size);
229 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
230
231 CREATE TABLE oldimage (
232 oi_name TEXT NOT NULL REFERENCES image(img_name),
233 oi_archive_name TEXT NOT NULL,
234 oi_size SMALLINT NOT NULL,
235 oi_width SMALLINT NOT NULL,
236 oi_height SMALLINT NOT NULL,
237 oi_bits SMALLINT NOT NULL,
238 oi_description TEXT,
239 oi_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
240 oi_user_text TEXT NOT NULL,
241 oi_timestamp TIMESTAMPTZ NOT NULL
242 );
243 CREATE INDEX oi_name ON oldimage (oi_name);
244
245
246 CREATE TABLE filearchive (
247 fa_id SERIAL NOT NULL PRIMARY KEY,
248 fa_name TEXT NOT NULL,
249 fa_archive_name TEXT,
250 fa_storage_group VARCHAR(16),
251 fa_storage_key CHAR(64),
252 fa_deleted_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
253 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
254 fa_deleted_reason TEXT,
255 fa_size SMALLINT NOT NULL,
256 fa_width SMALLINT NOT NULL,
257 fa_height SMALLINT NOT NULL,
258 fa_metadata TEXT,
259 fa_bits SMALLINT,
260 fa_media_type TEXT,
261 fa_major_mime TEXT DEFAULT 'unknown',
262 fa_minor_mime TEXT DEFAULT 'unknown',
263 fa_description TEXT NOT NULL,
264 fa_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
265 fa_user_text TEXT NOT NULL,
266 fa_timestamp TIMESTAMPTZ
267 );
268 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
269 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
270 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
271 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
272
273
274 CREATE SEQUENCE rc_rc_id_seq;
275 CREATE TABLE recentchanges (
276 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
277 rc_timestamp TIMESTAMPTZ NOT NULL,
278 rc_cur_time TIMESTAMPTZ NOT NULL,
279 rc_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
280 rc_user_text TEXT NOT NULL,
281 rc_namespace SMALLINT NOT NULL,
282 rc_title TEXT NOT NULL,
283 rc_comment TEXT,
284 rc_minor CHAR NOT NULL DEFAULT '0',
285 rc_bot CHAR NOT NULL DEFAULT '0',
286 rc_new CHAR NOT NULL DEFAULT '0',
287 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
288 rc_this_oldid INTEGER NOT NULL,
289 rc_last_oldid INTEGER NOT NULL,
290 rc_type CHAR NOT NULL DEFAULT '0',
291 rc_moved_to_ns SMALLINT,
292 rc_moved_to_title TEXT,
293 rc_patrolled CHAR NOT NULL DEFAULT '0',
294 rc_ip CIDR
295 );
296 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
297 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
298 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
299 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
300 CREATE INDEX rc_ip ON recentchanges (rc_ip);
301
302
303 CREATE TABLE watchlist (
304 wl_user INTEGER NOT NULL REFERENCES "user"(user_id) ON DELETE CASCADE,
305 wl_namespace SMALLINT NOT NULL DEFAULT 0,
306 wl_title TEXT NOT NULL,
307 wl_notificationtimestamp TIMESTAMPTZ
308 );
309 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
310
311
312 CREATE TABLE math (
313 math_inputhash TEXT NOT NULL UNIQUE,
314 math_outputhash TEXT NOT NULL,
315 math_html_conservativeness SMALLINT NOT NULL,
316 math_html TEXT,
317 math_mathml TEXT
318 );
319
320
321 CREATE TABLE interwiki (
322 iw_prefix TEXT NOT NULL UNIQUE,
323 iw_url TEXT NOT NULL,
324 iw_local CHAR NOT NULL,
325 iw_trans CHAR NOT NULL DEFAULT '0'
326 );
327
328
329 CREATE TABLE querycache (
330 qc_type TEXT NOT NULL,
331 qc_value SMALLINT NOT NULL,
332 qc_namespace SMALLINT NOT NULL,
333 qc_title TEXT NOT NULL
334 );
335 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
336
337 CREATE TABLE querycache_info (
338 qci_type TEXT UNIQUE,
339 qci_timestamp TIMESTAMPTZ NULL
340 );
341
342 CREATE TABLE objectcache (
343 keyname CHAR(255) UNIQUE,
344 value BYTEA NOT NULL DEFAULT '',
345 exptime TIMESTAMPTZ NOT NULL
346 );
347 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
348
349 CREATE TABLE transcache (
350 tc_url TEXT NOT NULL UNIQUE,
351 tc_contents TEXT NOT NULL,
352 tc_time TIMESTAMPTZ NOT NULL
353 );
354
355
356 CREATE TABLE logging (
357 log_type TEXT NOT NULL,
358 log_action TEXT NOT NULL,
359 log_timestamp TIMESTAMPTZ NOT NULL,
360 log_user INTEGER REFERENCES "user"(user_id) ON DELETE SET NULL,
361 log_namespace SMALLINT NOT NULL,
362 log_title TEXT NOT NULL,
363 log_comment TEXT,
364 log_params TEXT
365 );
366 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
367 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
368 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
369
370
371 CREATE TABLE trackbacks (
372 tb_id SERIAL NOT NULL PRIMARY KEY,
373 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
374 tb_title TEXT NOT NULL,
375 tb_url TEXT NOT NULL,
376 tb_ex TEXT,
377 tb_name TEXT
378 );
379 CREATE INDEX trackback_page ON trackbacks (tb_page);
380
381
382 CREATE SEQUENCE job_job_id_seq;
383 CREATE TABLE job (
384 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
385 job_cmd TEXT NOT NULL,
386 job_namespace SMALLINT NOT NULL,
387 job_title TEXT NOT NULL,
388 job_params TEXT NOT NULL
389 );
390 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
391
392 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
393
394 ALTER TABLE page ADD titlevector tsvector;
395 CREATE INDEX ts2_page_title ON page USING gist(titlevector);
396 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
397 $mw$
398 BEGIN
399 IF TG_OP = 'INSERT' THEN
400 NEW.titlevector = to_tsvector(NEW.page_title);
401 ELSIF NEW.page_title != OLD.page_title THEN
402 NEW.titlevector := to_tsvector(NEW.page_title);
403 END IF;
404 RETURN NEW;
405 END;
406 $mw$;
407
408 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
409 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
410
411
412 ALTER TABLE text ADD textvector tsvector;
413 CREATE INDEX ts2_page_text ON text USING gist(textvector);
414 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
415 $mw$
416 BEGIN
417 IF TG_OP = 'INSERT' THEN
418 NEW.textvector = to_tsvector(NEW.old_text);
419 ELSIF NEW.old_text != OLD.old_text THEN
420 NEW.textvector := to_tsvector(NEW.old_text);
421 END IF;
422 RETURN NEW;
423 END;
424 $mw$;
425
426 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON text
427 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
428
429 CREATE OR REPLACE FUNCTION add_interwiki (TEXT,INT,CHAR) RETURNS INT LANGUAGE SQL AS
430 $mw$
431 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
432 SELECT 1;
433 $mw$;
434
435 CREATE TABLE mediawiki_version (
436 type TEXT NOT NULL,
437 mw_version TEXT NOT NULL,
438
439 pg_version TEXT NULL,
440 pg_dbname TEXT NULL,
441 pg_user TEXT NULL,
442 pg_port TEXT NULL,
443 mw_schema TEXT NULL,
444 ts2_schema TEXT NULL,
445
446 sql_version TEXT NULL,
447 sql_date TEXT NULL,
448 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
449 );
450
451 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
452 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
453
454
455 COMMIT;