Add searchindex table back in, lots of reformatting.
[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, TEXT to CIDR, allow custom schema
9
10 SET client_min_messages = 'ERROR';
11
12 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
13 CREATE TABLE "user" (
14 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
15 user_name TEXT NOT NULL UNIQUE,
16 user_real_name TEXT,
17 user_password TEXT,
18 user_newpassword TEXT,
19 user_token CHAR(32),
20 user_email TEXT,
21 user_email_token CHAR(32),
22 user_email_token_expires TIMESTAMPTZ,
23 user_email_authenticated TIMESTAMPTZ,
24 user_options TEXT,
25 user_touched TIMESTAMPTZ,
26 user_registration TIMESTAMPTZ
27 );
28 CREATE INDEX user_email_token_idx ON "user" (user_email_token);
29
30 -- Create a dummy user to satisfy fk contraints especially with revisions
31 INSERT INTO "user" VALUES
32 (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
33
34 CREATE TABLE user_groups (
35 ug_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE CASCADE,
36 ug_group TEXT NOT NULL
37 );
38 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_group, ug_user);
39
40 CREATE TABLE user_newtalk (
41 user_id INTEGER NOT NULL REFERENCES "user"(user_id) ON DELETE CASCADE,
42 user_ip TEXT NULL
43 );
44 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
45 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
46
47
48 CREATE SEQUENCE page_page_id_seq;
49 CREATE TABLE page (
50 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
51 page_namespace SMALLINT NOT NULL,
52 page_title TEXT NOT NULL,
53 page_restrictions TEXT,
54 page_counter BIGINT NOT NULL DEFAULT 0,
55 page_is_redirect CHAR NOT NULL DEFAULT 0,
56 page_is_new CHAR NOT NULL DEFAULT 0,
57 page_random NUMERIC(15,14) NOT NULL,
58 page_touched TIMESTAMPTZ,
59 page_latest INTEGER NOT NULL, -- FK?
60 page_len INTEGER NOT NULL
61 );
62 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
63 CREATE INDEX page_random_idx ON page (page_random);
64 CREATE INDEX page_len_idx ON page (page_len);
65
66 -- Create a dummy page to satisfy fk contraints where a page_id of "0" is added
67 INSERT INTO page (page_id,page_namespace,page_title,page_random,page_latest,page_len)
68 VALUES (0,0,'',0.0,0,0);
69
70
71 CREATE SEQUENCE rev_rev_id_val;
72 CREATE TABLE revision (
73 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('rev_rev_id_val'),
74 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE SET NULL,
75 rev_text_id INTEGER NULL, -- FK
76 rev_comment TEXT,
77 rev_user INTEGER NOT NULL REFERENCES "user"(user_id),
78 rev_user_text TEXT NOT NULL,
79 rev_timestamp TIMESTAMPTZ NOT NULL,
80 rev_minor_edit CHAR NOT NULL DEFAULT '0',
81 rev_deleted CHAR NOT NULL DEFAULT '0'
82 );
83 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
84 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
85 CREATE INDEX rev_user_idx ON revision (rev_user);
86 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
87
88
89 CREATE SEQUENCE text_old_id_val;
90 CREATE TABLE "text" (
91 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_val'),
92 old_text TEXT,
93 old_flags TEXT
94 );
95
96
97 CREATE TABLE archive (
98 ar_namespace SMALLINT NOT NULL,
99 ar_title TEXT NOT NULL,
100 ar_text TEXT,
101 ar_comment TEXT,
102 ar_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
103 ar_user_text TEXT NOT NULL,
104 ar_timestamp TIMESTAMPTZ NOT NULL,
105 ar_minor_edit CHAR NOT NULL DEFAULT '0',
106 ar_flags TEXT,
107 ar_rev_id INTEGER,
108 ar_text_id INTEGER
109 );
110 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
111
112
113 CREATE TABLE pagelinks (
114 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
115 pl_namespace SMALLINT NOT NULL,
116 pl_title TEXT NOT NULL
117 );
118 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_namespace,pl_title,pl_from);
119
120 CREATE TABLE templatelinks (
121 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
122 tl_namespace TEXT NOT NULL,
123 tl_title TEXT NOT NULL
124 );
125 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
126
127 CREATE TABLE imagelinks (
128 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
129 il_to TEXT NOT NULL
130 );
131 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
132
133 CREATE TABLE categorylinks (
134 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
135 cl_to TEXT NOT NULL,
136 cl_sortkey TEXT,
137 cl_timestamp TIMESTAMPTZ NOT NULL
138 );
139 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
140 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey);
141
142 CREATE TABLE externallinks (
143 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
144 el_to TEXT NOT NULL,
145 el_index TEXT NOT NULL
146 );
147 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
148 CREATE INDEX externallinks_index ON externallinks (el_index);
149
150 CREATE TABLE langlinks (
151 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
152 ll_lang TEXT,
153 ll_title TEXT
154 );
155 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
156 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
157
158
159 CREATE TABLE site_stats (
160 ss_row_id INTEGER NOT NULL UNIQUE,
161 ss_total_views INTEGER DEFAULT 0,
162 ss_total_edits INTEGER DEFAULT 0,
163 ss_good_articles INTEGER DEFAULT 0,
164 ss_total_pages INTEGER DEFAULT -1,
165 ss_users INTEGER DEFAULT -1,
166 ss_admins INTEGER DEFAULT -1,
167 ss_images INTEGER DEFAULT 0
168 );
169
170 CREATE TABLE hitcounter (
171 hc_id BIGINT NOT NULL
172 );
173
174
175 CREATE SEQUENCE ipblocks_ipb_id_val;
176 CREATE TABLE ipblocks (
177 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
178 ipb_address TEXT NULL,
179 ipb_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
180 ipb_by INTEGER NOT NULL REFERENCES "user"(user_id) ON DELETE CASCADE,
181 ipb_reason TEXT NOT NULL,
182 ipb_timestamp TIMESTAMPTZ NOT NULL,
183 ipb_auto CHAR NOT NULL DEFAULT '0',
184 ipb_expiry TIMESTAMPTZ NOT NULL,
185 ipb_range_start TEXT,
186 ipb_range_end TEXT
187 );
188 CREATE INDEX ipb_address ON ipblocks (ipb_address);
189 CREATE INDEX ipb_user ON ipblocks (ipb_user);
190 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
191
192
193 CREATE TABLE image (
194 img_name TEXT NOT NULL PRIMARY KEY,
195 img_size SMALLINT NOT NULL,
196 img_width SMALLINT NOT NULL,
197 img_height SMALLINT NOT NULL,
198 img_metadata TEXT,
199 img_bits SMALLINT,
200 img_media_type TEXT,
201 img_major_mime TEXT DEFAULT 'unknown',
202 img_minor_mime TEXT DEFAULT 'unknown',
203 img_description TEXT NOT NULL,
204 img_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
205 img_user_text TEXT NOT NULL,
206 img_timestamp TIMESTAMPTZ
207 );
208 CREATE INDEX img_size_idx ON image (img_size);
209 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
210
211 CREATE TABLE oldimage (
212 oi_name TEXT NOT NULL REFERENCES image(img_name),
213 oi_archive_name TEXT NOT NULL,
214 oi_size SMALLINT NOT NULL,
215 oi_width SMALLINT NOT NULL,
216 oi_height SMALLINT NOT NULL,
217 oi_bits SMALLINT NOT NULL,
218 oi_description TEXT,
219 oi_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
220 oi_user_text TEXT NOT NULL,
221 oi_timestamp TIMESTAMPTZ NOT NULL
222 );
223 CREATE INDEX oi_name ON oldimage (oi_name);
224
225
226 CREATE TABLE filearchive (
227 fa_id SERIAL NOT NULL PRIMARY KEY,
228 fa_name TEXT NOT NULL,
229 fa_archive_name TEXT,
230 fa_storage_group VARCHAR(16),
231 fa_storage_key CHAR(64),
232 fa_deleted_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
233 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
234 fa_deleted_reason TEXT,
235 fa_size SMALLINT NOT NULL,
236 fa_width SMALLINT NOT NULL,
237 fa_height SMALLINT NOT NULL,
238 fa_metadata TEXT,
239 fa_bits SMALLINT,
240 fa_media_type TEXT,
241 fa_major_mime TEXT DEFAULT 'unknown',
242 fa_minor_mime TEXT DEFAULT 'unknown',
243 fa_description TEXT NOT NULL,
244 fa_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
245 fa_user_text TEXT NOT NULL,
246 fa_timestamp TIMESTAMPTZ
247 );
248 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
249 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
250 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
251 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
252
253
254 CREATE SEQUENCE rc_rc_id_seq;
255 CREATE TABLE recentchanges (
256 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
257 rc_timestamp TIMESTAMPTZ NOT NULL,
258 rc_cur_time TIMESTAMPTZ NOT NULL,
259 rc_user INTEGER NULL REFERENCES "user"(user_id) ON DELETE SET NULL,
260 rc_user_text TEXT NOT NULL,
261 rc_namespace SMALLINT NOT NULL,
262 rc_title TEXT NOT NULL,
263 rc_comment TEXT,
264 rc_minor CHAR NOT NULL DEFAULT '0',
265 rc_bot CHAR NOT NULL DEFAULT '0',
266 rc_new CHAR NOT NULL DEFAULT '0',
267 rc_cur_id INTEGER NOT NULL REFERENCES page(page_id),
268 rc_this_oldid INTEGER NOT NULL,
269 rc_last_oldid INTEGER NOT NULL,
270 rc_type CHAR NOT NULL DEFAULT '0',
271 rc_moved_to_ns SMALLINT,
272 rc_moved_to_title TEXT,
273 rc_patrolled CHAR NOT NULL DEFAULT '0',
274 rc_ip TEXT
275 );
276 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
277 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
278 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
279 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
280 CREATE INDEX rc_ip ON recentchanges (rc_ip);
281
282
283 CREATE TABLE watchlist (
284 wl_user INTEGER NOT NULL REFERENCES "user"(user_id) ON DELETE CASCADE,
285 wl_namespace SMALLINT NOT NULL DEFAULT 0,
286 wl_title TEXT NOT NULL,
287 wl_notificationtimestamp TIMESTAMPTZ
288 );
289 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
290
291
292 CREATE TABLE math (
293 math_inputhash TEXT NOT NULL UNIQUE,
294 math_outputhash TEXT NOT NULL,
295 math_html_conservativeness SMALLINT NOT NULL,
296 math_html TEXT,
297 math_mathml TEXT
298 );
299
300
301 CREATE TABLE interwiki (
302 iw_prefix TEXT NOT NULL UNIQUE,
303 iw_url TEXT NOT NULL,
304 iw_local CHAR NOT NULL,
305 iw_trans CHAR NOT NULL DEFAULT '0'
306 );
307
308
309 CREATE TABLE querycache (
310 qc_type TEXT NOT NULL,
311 qc_value SMALLINT NOT NULL,
312 qc_namespace SMALLINT NOT NULL,
313 qc_title TEXT NOT NULL
314 );
315 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
316
317 CREATE TABLE querycache_info (
318 qci_type TEXT UNIQUE,
319 qci_timestamp TIMESTAMPTZ NULL
320 );
321
322 CREATE TABLE objectcache (
323 keyname CHAR(255) UNIQUE,
324 value TEXT NOT NULL DEFAULT '',
325 exptime TIMESTAMPTZ NOT NULL
326 );
327 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
328
329 CREATE TABLE transcache (
330 tc_url TEXT NOT NULL UNIQUE,
331 tc_contents TEXT NOT NULL,
332 tc_time TIMESTAMPTZ NOT NULL
333 );
334
335
336 CREATE TABLE logging (
337 log_type TEXT NOT NULL,
338 log_action TEXT NOT NULL,
339 log_timestamp TIMESTAMPTZ NOT NULL,
340 log_user INTEGER REFERENCES "user"(user_id) ON DELETE SET NULL,
341 log_namespace SMALLINT NOT NULL,
342 log_title TEXT NOT NULL,
343 log_comment TEXT,
344 log_params TEXT
345 );
346 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
347 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
348 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
349
350
351 CREATE TABLE trackbacks (
352 tb_id SERIAL NOT NULL PRIMARY KEY,
353 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
354 tb_title TEXT NOT NULL,
355 tb_url TEXT NOT NULL,
356 tb_ex TEXT,
357 tb_name TEXT
358 );
359 CREATE INDEX trackback_page ON trackbacks (tb_page);
360
361
362 CREATE SEQUENCE job_job_id_seq;
363 CREATE TABLE job (
364 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
365 job_cmd TEXT NOT NULL,
366 job_namespace SMALLINT NOT NULL,
367 job_title TEXT NOT NULL,
368 job_params TEXT NOT NULL
369 );
370 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
371
372
373 CREATE TABLE searchindex (
374 si_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
375 si_title VARCHAR(255) NOT NULL DEFAULT '',
376 si_text TEXT NOT NULL DEFAULT ''
377 );
378
379
380
381 CREATE OR REPLACE FUNCTION add_interwiki (TEXT,INT,CHAR) RETURNS INT LANGUAGE SQL AS
382 $mw$
383 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
384 SELECT 1;
385 $mw$;