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