Duplicate column.
[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 CIDR 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_expiry TIMESTAMPTZ NOT NULL,
223 ipb_range_start TEXT,
224 ipb_range_end TEXT
225 );
226 CREATE INDEX ipb_address ON ipblocks (ipb_address);
227 CREATE INDEX ipb_user ON ipblocks (ipb_user);
228 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
229
230
231 CREATE TABLE image (
232 img_name TEXT NOT NULL PRIMARY KEY,
233 img_size INTEGER NOT NULL,
234 img_width INTEGER NOT NULL,
235 img_height INTEGER NOT NULL,
236 img_metadata TEXT,
237 img_bits SMALLINT,
238 img_media_type TEXT,
239 img_major_mime TEXT DEFAULT 'unknown',
240 img_minor_mime TEXT DEFAULT 'unknown',
241 img_description TEXT NOT NULL,
242 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
243 img_user_text TEXT NOT NULL,
244 img_timestamp TIMESTAMPTZ
245 );
246 CREATE INDEX img_size_idx ON image (img_size);
247 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
248
249 CREATE TABLE oldimage (
250 oi_name TEXT NOT NULL REFERENCES image(img_name),
251 oi_archive_name TEXT NOT NULL,
252 oi_size INTEGER NOT NULL,
253 oi_width INTEGER NOT NULL,
254 oi_height INTEGER NOT NULL,
255 oi_bits SMALLINT NOT NULL,
256 oi_description TEXT,
257 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
258 oi_user_text TEXT NOT NULL,
259 oi_timestamp TIMESTAMPTZ NOT NULL
260 );
261 CREATE INDEX oi_name ON oldimage (oi_name);
262
263
264 CREATE TABLE filearchive (
265 fa_id SERIAL NOT NULL PRIMARY KEY,
266 fa_name TEXT NOT NULL,
267 fa_archive_name TEXT,
268 fa_storage_group VARCHAR(16),
269 fa_storage_key CHAR(64),
270 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
271 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
272 fa_deleted_reason TEXT,
273 fa_size SMALLINT NOT NULL,
274 fa_width SMALLINT NOT NULL,
275 fa_height SMALLINT NOT NULL,
276 fa_metadata TEXT,
277 fa_bits SMALLINT,
278 fa_media_type TEXT,
279 fa_major_mime TEXT DEFAULT 'unknown',
280 fa_minor_mime TEXT DEFAULT 'unknown',
281 fa_description TEXT NOT NULL,
282 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
283 fa_user_text TEXT NOT NULL,
284 fa_timestamp TIMESTAMPTZ
285 );
286 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
287 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
288 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
289 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
290
291
292 CREATE SEQUENCE rc_rc_id_seq;
293 CREATE TABLE recentchanges (
294 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
295 rc_timestamp TIMESTAMPTZ NOT NULL,
296 rc_cur_time TIMESTAMPTZ NOT NULL,
297 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
298 rc_user_text TEXT NOT NULL,
299 rc_namespace SMALLINT NOT NULL,
300 rc_title TEXT NOT NULL,
301 rc_comment TEXT,
302 rc_minor CHAR NOT NULL DEFAULT '0',
303 rc_bot CHAR NOT NULL DEFAULT '0',
304 rc_new CHAR NOT NULL DEFAULT '0',
305 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
306 rc_this_oldid INTEGER NOT NULL,
307 rc_last_oldid INTEGER NOT NULL,
308 rc_type CHAR NOT NULL DEFAULT '0',
309 rc_moved_to_ns SMALLINT,
310 rc_moved_to_title TEXT,
311 rc_patrolled CHAR NOT NULL DEFAULT '0',
312 rc_ip CIDR
313 );
314 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
315 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
316 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
317 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
318 CREATE INDEX rc_ip ON recentchanges (rc_ip);
319
320
321 CREATE TABLE watchlist (
322 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
323 wl_namespace SMALLINT NOT NULL DEFAULT 0,
324 wl_title TEXT NOT NULL,
325 wl_notificationtimestamp TIMESTAMPTZ
326 );
327 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
328
329
330 CREATE TABLE math (
331 math_inputhash TEXT NOT NULL UNIQUE,
332 math_outputhash TEXT NOT NULL,
333 math_html_conservativeness SMALLINT NOT NULL,
334 math_html TEXT,
335 math_mathml TEXT
336 );
337
338
339 CREATE TABLE interwiki (
340 iw_prefix TEXT NOT NULL UNIQUE,
341 iw_url TEXT NOT NULL,
342 iw_local CHAR NOT NULL,
343 iw_trans CHAR NOT NULL DEFAULT '0'
344 );
345
346
347 CREATE TABLE querycache (
348 qc_type TEXT NOT NULL,
349 qc_value SMALLINT NOT NULL,
350 qc_namespace SMALLINT NOT NULL,
351 qc_title TEXT NOT NULL
352 );
353 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
354
355 CREATE TABLE querycache_info (
356 qci_type TEXT UNIQUE,
357 qci_timestamp TIMESTAMPTZ NULL
358 );
359
360 CREATE TABLE querycachetwo (
361 qcc_type TEXT NOT NULL,
362 qcc_value SMALLINT NOT NULL DEFAULT 0,
363 qcc_namespace INTEGER NOT NULL DEFAULT 0,
364 qcc_title TEXT NOT NULL DEFAULT '',
365 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
366 qcc_titletwo TEXT NOT NULL DEFAULT ''
367 );
368 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
369 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
370 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
371
372
373 CREATE TABLE objectcache (
374 keyname CHAR(255) UNIQUE,
375 value BYTEA NOT NULL DEFAULT '',
376 exptime TIMESTAMPTZ NOT NULL
377 );
378 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
379
380 CREATE TABLE transcache (
381 tc_url TEXT NOT NULL UNIQUE,
382 tc_contents TEXT NOT NULL,
383 tc_time TIMESTAMPTZ NOT NULL
384 );
385
386
387 CREATE TABLE logging (
388 log_type TEXT NOT NULL,
389 log_action TEXT NOT NULL,
390 log_timestamp TIMESTAMPTZ NOT NULL,
391 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
392 log_namespace SMALLINT NOT NULL,
393 log_title TEXT NOT NULL,
394 log_comment TEXT,
395 log_params TEXT
396 );
397 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
398 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
399 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
400
401
402 CREATE TABLE trackbacks (
403 tb_id SERIAL NOT NULL PRIMARY KEY,
404 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
405 tb_title TEXT NOT NULL,
406 tb_url TEXT NOT NULL,
407 tb_ex TEXT,
408 tb_name TEXT
409 );
410 CREATE INDEX trackback_page ON trackbacks (tb_page);
411
412
413 CREATE SEQUENCE job_job_id_seq;
414 CREATE TABLE job (
415 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
416 job_cmd TEXT NOT NULL,
417 job_namespace SMALLINT NOT NULL,
418 job_title TEXT NOT NULL,
419 job_params TEXT NOT NULL
420 );
421 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
422
423 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
424
425 ALTER TABLE page ADD titlevector tsvector;
426 CREATE INDEX ts2_page_title ON page USING gist(titlevector);
427 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
428 $mw$
429 BEGIN
430 IF TG_OP = 'INSERT' THEN
431 NEW.titlevector = to_tsvector('default',NEW.page_title);
432 ELSIF NEW.page_title != OLD.page_title THEN
433 NEW.titlevector := to_tsvector('default',NEW.page_title);
434 END IF;
435 RETURN NEW;
436 END;
437 $mw$;
438
439 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
440 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
441
442
443 ALTER TABLE pagecontent ADD textvector tsvector;
444 CREATE INDEX ts2_page_text ON pagecontent USING gist(textvector);
445 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
446 $mw$
447 BEGIN
448 IF TG_OP = 'INSERT' THEN
449 NEW.textvector = to_tsvector('default',NEW.old_text);
450 ELSIF NEW.old_text != OLD.old_text THEN
451 NEW.textvector := to_tsvector('default',NEW.old_text);
452 END IF;
453 RETURN NEW;
454 END;
455 $mw$;
456
457 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
458 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
459
460 CREATE FUNCTION add_interwiki (TEXT,INT,CHAR) RETURNS INT LANGUAGE SQL AS
461 $mw$
462 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
463 SELECT 1;
464 $mw$;
465
466 -- This table is not used unless profiling is turned on
467 CREATE TABLE profiling (
468 pf_count INTEGER NOT NULL DEFAULT 0,
469 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
470 pf_name TEXT NOT NULL,
471 pf_server TEXT NULL
472 );
473 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
474
475
476 CREATE TABLE mediawiki_version (
477 type TEXT NOT NULL,
478 mw_version TEXT NOT NULL,
479 notes TEXT NULL,
480
481 pg_version TEXT NULL,
482 pg_dbname TEXT NULL,
483 pg_user TEXT NULL,
484 pg_port TEXT NULL,
485 mw_schema TEXT NULL,
486 ts2_schema TEXT NULL,
487 ctype TEXT NULL,
488
489 sql_version TEXT NULL,
490 sql_date TEXT NULL,
491 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
492 );
493
494 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
495 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
496
497
498 COMMIT;