Decouple revision.rev_id from text.old_id
[lhc/web/wiklou.git] / maintenance / tables.sql
1 -- SQL to create the initial tables for the Wikipedia database.
2 -- This is read and executed by the install script; you should
3 -- never have to run it by itself.
4 --
5 -- Indexes should be defined here; please import the rest from indexes.sql.
6
7 CREATE TABLE /*$wgDBprefix*/user (
8 user_id int(5) unsigned NOT NULL auto_increment,
9 user_name varchar(255) binary NOT NULL default '',
10 user_real_name varchar(255) binary NOT NULL default '',
11 user_password tinyblob NOT NULL default '',
12 user_newpassword tinyblob NOT NULL default '',
13 user_email tinytext NOT NULL default '',
14 user_emailauthenticationtimestamp varchar(14) binary NOT NULL default '0',
15 user_options blob NOT NULL default '',
16 user_touched char(14) binary NOT NULL default '',
17 user_token char(32) binary NOT NULL default '',
18 PRIMARY KEY user_id (user_id),
19 INDEX user_name (user_name(10))
20 );
21
22 -- TODO: de-blob this; it should be a property table
23 CREATE TABLE /*$wgDBprefix*/user_rights (
24 ur_user int(5) unsigned NOT NULL,
25 ur_rights tinyblob NOT NULL default '',
26 UNIQUE KEY ur_user (ur_user)
27 );
28
29 -- The following table is no longer needed with Enotif >= 2.00
30 -- Entries for newtalk on user_talk page are handled like in the watchlist table
31 -- CREATE TABLE /*$wgDBprefix*/user_newtalk (
32 -- user_id int(5) NOT NULL default '0',
33 -- user_ip varchar(40) NOT NULL default '',
34 -- INDEX user_id (user_id),
35 -- INDEX user_ip (user_ip)
36 -- );
37
38 CREATE TABLE /*$wgDBprefix*/page (
39 -- Identifiers:
40 page_id int(8) unsigned NOT NULL auto_increment,
41 page_namespace tinyint NOT NULL,
42 page_title varchar(255) binary NOT NULL,
43
44 -- Mutable information
45 page_restrictions tinyblob NOT NULL default '',
46 page_counter bigint(20) unsigned NOT NULL default '0',
47 page_is_redirect tinyint(1) unsigned NOT NULL default '0',
48 page_is_new tinyint(1) unsigned NOT NULL default '0',
49 page_random real unsigned NOT NULL,
50 page_touched char(14) binary NOT NULL default '',
51
52 -- Handy key to revision.rev_id of the current revision
53 page_latest int(8) unsigned NOT NULL,
54 page_len int(8) unsigned NOT NULL,
55
56 PRIMARY KEY page_id (page_id),
57 UNIQUE INDEX name_title (page_namespace,page_title),
58
59 -- Special-purpose indexes
60 INDEX (page_random),
61 INDEX (page_len)
62 );
63
64 CREATE TABLE /*$wgDBprefix*/revision (
65 rev_id int(8) unsigned NOT NULL auto_increment,
66 rev_page int(8) unsigned NOT NULL,
67 rev_text_id int(8) unsigned NOT NULL,
68 rev_comment tinyblob NOT NULL default '',
69 rev_user int(5) unsigned NOT NULL default '0',
70 rev_user_text varchar(255) binary NOT NULL default '',
71 rev_timestamp char(14) binary NOT NULL default '',
72 rev_minor_edit tinyint(1) unsigned NOT NULL default '0',
73
74 PRIMARY KEY rev_page_id (rev_page, rev_id),
75 UNIQUE INDEX rev_id (rev_id),
76 INDEX rev_timestamp (rev_timestamp),
77 INDEX page_timestamp (rev_page,rev_timestamp),
78 INDEX user_timestamp (rev_user,rev_timestamp),
79 INDEX usertext_timestamp (rev_user_text,rev_timestamp)
80 );
81
82
83 --
84 -- Holds text of individual page revisions.
85 --
86 CREATE TABLE /*$wgDBprefix*/text (
87 old_id int(8) unsigned NOT NULL auto_increment,
88 old_text mediumtext NOT NULL default '',
89 old_flags tinyblob NOT NULL default '',
90
91 PRIMARY KEY old_id (old_id)
92 );
93
94 CREATE TABLE /*$wgDBprefix*/archive (
95 ar_namespace tinyint(2) unsigned NOT NULL default '0',
96 ar_title varchar(255) binary NOT NULL default '',
97 ar_text mediumtext NOT NULL default '',
98 ar_comment tinyblob NOT NULL default '',
99 ar_user int(5) unsigned NOT NULL default '0',
100 ar_user_text varchar(255) binary NOT NULL,
101 ar_timestamp char(14) binary NOT NULL default '',
102 ar_minor_edit tinyint(1) NOT NULL default '0',
103 ar_flags tinyblob NOT NULL default '',
104 ar_rev_id int(8) unsigned,
105
106 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp)
107 );
108
109 --
110 -- Track links that do exist
111 -- l_from and l_to key to cur_id
112 --
113 CREATE TABLE /*$wgDBprefix*/links (
114 l_from int(8) unsigned NOT NULL default '0',
115 l_to int(8) unsigned NOT NULL default '0',
116 UNIQUE KEY l_from(l_from,l_to),
117 KEY (l_to)
118 );
119
120 --
121 -- Track links to pages that don't yet exist.
122 -- bl_from keys to cur_id
123 -- bl_to is a text link (namespace:title)
124 --
125 CREATE TABLE /*$wgDBprefix*/brokenlinks (
126 bl_from int(8) unsigned NOT NULL default '0',
127 bl_to varchar(255) binary NOT NULL default '',
128 UNIQUE KEY bl_from(bl_from,bl_to),
129 KEY (bl_to)
130 );
131
132 --
133 -- Track links to images *used inline*
134 -- il_from keys to cur_id, il_to keys to image_name.
135 -- We don't distinguish live from broken links.
136 --
137 CREATE TABLE /*$wgDBprefix*/imagelinks (
138 il_from int(8) unsigned NOT NULL default '0',
139 il_to varchar(255) binary NOT NULL default '',
140 UNIQUE KEY il_from(il_from,il_to),
141 KEY (il_to)
142 );
143
144 --
145 -- Track category inclusions *used inline*
146 -- cl_from keys to cur_id, cl_to keys to cur_title of the category page.
147 -- cl_sortkey is the title of the linking page or an optional override
148 -- cl_timestamp marks when the link was last added
149 --
150 CREATE TABLE /*$wgDBprefix*/categorylinks (
151 cl_from int(8) unsigned NOT NULL default '0',
152 cl_to varchar(255) binary NOT NULL default '',
153 cl_sortkey varchar(255) binary NOT NULL default '',
154 cl_timestamp timestamp NOT NULL,
155 UNIQUE KEY cl_from(cl_from,cl_to),
156 KEY cl_sortkey(cl_to,cl_sortkey(128)),
157 KEY cl_timestamp(cl_to,cl_timestamp)
158 );
159
160 --
161 -- Stores (possibly gzipped) serialized objects with
162 -- cache arrays to reduce database load slurping up
163 -- from links and brokenlinks.
164 --
165 CREATE TABLE /*$wgDBprefix*/linkscc (
166 lcc_pageid INT UNSIGNED NOT NULL UNIQUE KEY,
167 lcc_cacheobj MEDIUMBLOB NOT NULL
168 );
169
170 CREATE TABLE /*$wgDBprefix*/site_stats (
171 ss_row_id int(8) unsigned NOT NULL,
172 ss_total_views bigint(20) unsigned default '0',
173 ss_total_edits bigint(20) unsigned default '0',
174 ss_good_articles bigint(20) unsigned default '0',
175 UNIQUE KEY ss_row_id (ss_row_id)
176 );
177
178 CREATE TABLE /*$wgDBprefix*/hitcounter (
179 hc_id INTEGER UNSIGNED NOT NULL
180 ) TYPE=HEAP MAX_ROWS=25000;
181
182 CREATE TABLE /*$wgDBprefix*/ipblocks (
183 ipb_id int(8) NOT NULL auto_increment,
184 ipb_address varchar(40) binary NOT NULL default '',
185 ipb_user int(8) unsigned NOT NULL default '0',
186 ipb_by int(8) unsigned NOT NULL default '0',
187 ipb_reason tinyblob NOT NULL default '',
188 ipb_timestamp char(14) binary NOT NULL default '',
189 ipb_auto tinyint(1) NOT NULL default '0',
190 ipb_expiry char(14) binary NOT NULL default '',
191
192 PRIMARY KEY ipb_id (ipb_id),
193 INDEX ipb_address (ipb_address),
194 INDEX ipb_user (ipb_user)
195 );
196
197 CREATE TABLE /*$wgDBprefix*/image (
198 img_name varchar(255) binary NOT NULL default '',
199 img_size int(8) unsigned NOT NULL default '0',
200 img_description tinyblob NOT NULL default '',
201 img_user int(5) unsigned NOT NULL default '0',
202 img_user_text varchar(255) binary NOT NULL default '',
203 img_timestamp char(14) binary NOT NULL default '',
204 PRIMARY KEY img_name (img_name),
205 INDEX img_size (img_size),
206 INDEX img_timestamp (img_timestamp)
207 );
208
209 CREATE TABLE /*$wgDBprefix*/oldimage (
210 oi_name varchar(255) binary NOT NULL default '',
211 oi_archive_name varchar(255) binary NOT NULL default '',
212 oi_size int(8) unsigned NOT NULL default 0,
213 oi_description tinyblob NOT NULL default '',
214 oi_user int(5) unsigned NOT NULL default '0',
215 oi_user_text varchar(255) binary NOT NULL default '',
216 oi_timestamp char(14) binary NOT NULL default '',
217 INDEX oi_name (oi_name(10))
218 );
219
220 CREATE TABLE /*$wgDBprefix*/recentchanges (
221 rc_id int(8) NOT NULL auto_increment,
222 rc_timestamp varchar(14) binary NOT NULL default '',
223 rc_cur_time varchar(14) binary NOT NULL default '',
224 rc_user int(10) unsigned NOT NULL default '0',
225 rc_user_text varchar(255) binary NOT NULL default '',
226 rc_namespace tinyint(3) NOT NULL default '0',
227 rc_title varchar(255) binary NOT NULL default '',
228 rc_comment varchar(255) binary NOT NULL default '',
229 rc_minor tinyint(3) unsigned NOT NULL default '0',
230 rc_bot tinyint(3) unsigned NOT NULL default '0',
231 rc_new tinyint(3) unsigned NOT NULL default '0',
232 rc_cur_id int(10) unsigned NOT NULL default '0',
233 rc_this_oldid int(10) unsigned NOT NULL default '0',
234 rc_last_oldid int(10) unsigned NOT NULL default '0',
235 rc_type tinyint(3) unsigned NOT NULL default '0',
236 rc_moved_to_ns tinyint(3) unsigned NOT NULL default '0',
237 rc_moved_to_title varchar(255) binary NOT NULL default '',
238 rc_patrolled tinyint(3) unsigned NOT NULL default '0',
239 rc_ip char(15) NOT NULL default '',
240
241 PRIMARY KEY rc_id (rc_id),
242 INDEX rc_timestamp (rc_timestamp),
243 INDEX rc_namespace_title (rc_namespace, rc_title),
244 INDEX rc_cur_id (rc_cur_id),
245 INDEX new_name_timestamp(rc_new,rc_namespace,rc_timestamp),
246 INDEX rc_ip (rc_ip)
247 );
248
249 CREATE TABLE /*$wgDBprefix*/watchlist (
250 wl_user int(5) unsigned NOT NULL,
251 wl_namespace tinyint(2) unsigned NOT NULL default '0',
252 wl_title varchar(255) binary NOT NULL default '',
253 wl_notificationtimestamp varchar(14) binary NOT NULL default '0',
254 UNIQUE KEY (wl_user, wl_namespace, wl_title),
255 KEY namespace_title (wl_namespace,wl_title)
256 );
257
258 CREATE TABLE /*$wgDBprefix*/math (
259 math_inputhash varchar(16) NOT NULL,
260 math_outputhash varchar(16) NOT NULL,
261 math_html_conservativeness tinyint(1) NOT NULL,
262 math_html text,
263 math_mathml text,
264 UNIQUE KEY math_inputhash (math_inputhash)
265 );
266
267
268 -- Table searchindex must be MyISAM for fulltext support
269
270 CREATE TABLE /*$wgDBprefix*/searchindex (
271 si_page int(8) unsigned NOT NULL,
272 si_title varchar(255) NOT NULL default '',
273 si_text mediumtext NOT NULL default '',
274 UNIQUE KEY (si_page),
275 FULLTEXT si_title (si_title),
276 FULLTEXT si_text (si_text)
277
278 ) TYPE=MyISAM;
279
280 CREATE TABLE /*$wgDBprefix*/interwiki (
281 iw_prefix char(32) NOT NULL,
282 iw_url char(127) NOT NULL,
283 iw_local BOOL NOT NULL,
284 UNIQUE KEY iw_prefix (iw_prefix)
285 );
286
287 -- Used for caching expensive grouped queries
288 CREATE TABLE /*$wgDBprefix*/querycache (
289 qc_type char(32) NOT NULL,
290 qc_value int(5) unsigned NOT NULL default '0',
291 qc_namespace tinyint(2) unsigned NOT NULL default '0',
292 qc_title char(255) binary NOT NULL default '',
293 KEY (qc_type,qc_value)
294 );
295
296 -- For a few generic cache operations if not using Memcached
297 CREATE TABLE /*$wgDBprefix*/objectcache (
298 keyname char(255) binary not null default '',
299 value mediumblob,
300 exptime datetime,
301 unique key (keyname),
302 key (exptime)
303 );
304
305 -- For storing revision text
306 CREATE TABLE /*$wgDBprefix*/blobs (
307 blob_index char(255) binary NOT NULL default '',
308 blob_data longblob NOT NULL default '',
309 UNIQUE key blob_index (blob_index)
310 );
311
312 -- For article validation
313
314 CREATE TABLE /*$wgDBprefix*/validate (
315 `val_user` int(11) NOT NULL default '0',
316 `val_page` int(11) unsigned NOT NULL default '0',
317 `val_revision` int(11) unsigned NOT NULL default '0',
318 `val_type` int(11) unsigned NOT NULL default '0',
319 `val_value` int(11) default '0',
320 `val_comment` varchar(255) NOT NULL default '',
321 KEY `val_user` (`val_user`,`val_revision`)
322 ) TYPE=MyISAM;
323
324 CREATE TABLE /*$wgDBprefix*/logging (
325 -- Symbolic keys for the general log type and the action type
326 -- within the log. The output format will be controlled by the
327 -- action field, but only the type controls categorization.
328 log_type char(10) NOT NULL default '',
329 log_action char(10) NOT NULL default '',
330
331 -- Timestamp. Duh.
332 log_timestamp char(14) NOT NULL default '19700101000000',
333
334 -- The user who performed this action; key to user_id
335 log_user int unsigned NOT NULL default 0,
336
337 -- Key to the page affected. Where a user is the target,
338 -- this will point to the user page.
339 log_namespace tinyint unsigned NOT NULL default 0,
340 log_title varchar(255) binary NOT NULL default '',
341
342 -- Freeform text. Interpreted as edit history comments.
343 log_comment varchar(255) NOT NULL default '',
344
345 -- LF separated list of miscellaneous parameters
346 log_params blob NOT NULL default '',
347
348 KEY type_time (log_type, log_timestamp),
349 KEY user_time (log_user, log_timestamp),
350 KEY page_time (log_namespace, log_title, log_timestamp)
351 );
352
353
354
355
356
357 -- Hold group name and description
358 CREATE TABLE /*$wgDBprefix*/`group` (
359 group_id int(5) unsigned NOT NULL auto_increment,
360 group_name varchar(50) NOT NULL default '',
361 group_description varchar(255) NOT NULL default '',
362 group_rights tinyblob,
363 PRIMARY KEY (group_id)
364 );
365
366 -- Relation table between user and groups
367 CREATE TABLE /*$wgDBprefix*/user_groups (
368 ug_user int(5) unsigned NOT NULL default '0',
369 ug_group int(5) unsigned NOT NULL default '0',
370 PRIMARY KEY (ug_user,ug_group)
371 );