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