3cba408eee1994af014009401926615200f612d1
[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 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_options blob NOT NULL default '',
15 user_touched char(14) binary NOT NULL default '',
16 PRIMARY KEY user_id (user_id),
17 INDEX user_name (user_name(10))
18 );
19
20 -- TODO: de-blob this; it should be a property table
21 CREATE TABLE user_rights (
22 user_id int(5) unsigned NOT NULL,
23 user_rights tinyblob NOT NULL default '',
24 UNIQUE KEY user_id (user_id)
25 );
26
27 CREATE TABLE user_newtalk (
28 user_id int(5) NOT NULL default '0',
29 user_ip varchar(40) NOT NULL default '',
30 INDEX user_id (user_id),
31 INDEX user_ip (user_ip)
32 );
33
34 CREATE TABLE cur (
35 cur_id int(8) unsigned NOT NULL auto_increment,
36 cur_namespace tinyint(2) unsigned NOT NULL default '0',
37 cur_title varchar(255) binary NOT NULL default '',
38 cur_text mediumtext NOT NULL default '',
39 cur_comment tinyblob NOT NULL default '',
40 cur_user int(5) unsigned NOT NULL default '0',
41 cur_user_text varchar(255) binary NOT NULL default '',
42 cur_timestamp char(14) binary NOT NULL default '',
43 cur_restrictions tinyblob NOT NULL default '',
44 cur_counter bigint(20) unsigned NOT NULL default '0',
45 cur_is_redirect tinyint(1) unsigned NOT NULL default '0',
46 cur_minor_edit tinyint(1) unsigned NOT NULL default '0',
47 cur_is_new tinyint(1) unsigned NOT NULL default '0',
48 cur_random real unsigned NOT NULL,
49 cur_touched char(14) binary NOT NULL default '',
50 inverse_timestamp char(14) binary NOT NULL default '',
51 PRIMARY KEY cur_id (cur_id),
52 UNIQUE INDEX name_title (cur_namespace,cur_title),
53
54 -- Is this one necessary?
55 INDEX cur_title (cur_title(20)),
56
57 INDEX cur_timestamp (cur_timestamp),
58 INDEX (cur_random),
59 INDEX name_title_timestamp (cur_namespace,cur_title,inverse_timestamp),
60 INDEX user_timestamp (cur_user,inverse_timestamp),
61 INDEX usertext_timestamp (cur_user_text,inverse_timestamp),
62 INDEX namespace_redirect_timestamp(cur_namespace,cur_is_redirect,cur_timestamp)
63 );
64
65 CREATE TABLE old (
66 old_id int(8) unsigned NOT NULL auto_increment,
67 old_namespace tinyint(2) unsigned NOT NULL default '0',
68 old_title varchar(255) binary NOT NULL default '',
69 old_text mediumtext NOT NULL default '',
70 old_comment tinyblob NOT NULL default '',
71 old_user int(5) unsigned NOT NULL default '0',
72 old_user_text varchar(255) binary NOT NULL,
73 old_timestamp char(14) binary NOT NULL default '',
74 old_minor_edit tinyint(1) NOT NULL default '0',
75 old_flags tinyblob NOT NULL default '',
76 inverse_timestamp char(14) binary NOT NULL default '',
77
78 PRIMARY KEY old_id (old_id),
79 INDEX old_timestamp (old_timestamp),
80 INDEX name_title_timestamp (old_namespace,old_title,inverse_timestamp),
81 INDEX user_timestamp (old_user,inverse_timestamp),
82 INDEX usertext_timestamp (old_user_text,inverse_timestamp)
83 );
84
85 CREATE TABLE archive (
86 ar_namespace tinyint(2) unsigned NOT NULL default '0',
87 ar_title varchar(255) binary NOT NULL default '',
88 ar_text mediumtext NOT NULL default '',
89 ar_comment tinyblob NOT NULL default '',
90 ar_user int(5) unsigned NOT NULL default '0',
91 ar_user_text varchar(255) binary NOT NULL,
92 ar_timestamp char(14) binary NOT NULL default '',
93 ar_minor_edit tinyint(1) NOT NULL default '0',
94 ar_flags tinyblob NOT NULL default '',
95
96 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp)
97 );
98
99 --
100 -- Track links that do exist
101 -- l_from and l_to key to cur_id
102 --
103 CREATE TABLE links (
104 l_from int(8) unsigned NOT NULL default '0',
105 l_to int(8) unsigned NOT NULL default '0',
106 UNIQUE KEY l_from(l_from,l_to),
107 KEY (l_to)
108 );
109
110 --
111 -- Track links to pages that don't yet exist.
112 -- bl_from keys to cur_id
113 -- bl_to is a text link (namespace:title)
114 --
115 CREATE TABLE brokenlinks (
116 bl_from int(8) unsigned NOT NULL default '0',
117 bl_to varchar(255) binary NOT NULL default '',
118 UNIQUE KEY bl_from(bl_from,bl_to),
119 KEY (bl_to)
120 );
121
122 --
123 -- Track links to images *used inline*
124 -- il_from keys to cur_id, il_to keys to image_name.
125 -- We don't distinguish live from broken links.
126 --
127 CREATE TABLE imagelinks (
128 il_from int(8) unsigned NOT NULL default '0',
129 il_to varchar(255) binary NOT NULL default '',
130 UNIQUE KEY il_from(il_from,il_to),
131 KEY (il_to)
132 );
133
134 --
135 -- Track category inclusions *used inline*
136 -- cl_from keys to cur_id, cl_to keys to cur_title of the category page.
137 -- cl_sortkey is the title of the linking page or an optional override
138 -- cl_timestamp marks when the link was last added
139 --
140 CREATE TABLE categorylinks (
141 cl_from int(8) unsigned NOT NULL default '0',
142 cl_to varchar(255) binary NOT NULL default '',
143 cl_sortkey varchar(255) binary NOT NULL default '',
144 cl_timestamp timestamp NOT NULL,
145 UNIQUE KEY cl_from(cl_from,cl_to),
146 KEY cl_sortkey(cl_to,cl_sortkey(128)),
147 KEY cl_timestamp(cl_to,cl_timestamp)
148 );
149
150 --
151 -- Stores (possibly gzipped) serialized objects with
152 -- cache arrays to reduce database load slurping up
153 -- from links and brokenlinks.
154 --
155 CREATE TABLE linkscc (
156 lcc_pageid INT UNSIGNED NOT NULL UNIQUE KEY,
157 lcc_cacheobj MEDIUMBLOB NOT NULL
158 );
159
160 CREATE TABLE site_stats (
161 ss_row_id int(8) unsigned NOT NULL,
162 ss_total_views bigint(20) unsigned default '0',
163 ss_total_edits bigint(20) unsigned default '0',
164 ss_good_articles bigint(20) unsigned default '0',
165 UNIQUE KEY ss_row_id (ss_row_id)
166 );
167
168 CREATE TABLE hitcounter (
169 hc_id INTEGER UNSIGNED NOT NULL
170 ) TYPE=HEAP MAX_ROWS=25000;
171
172 CREATE TABLE ipblocks (
173 ipb_id int(8) NOT NULL auto_increment,
174 ipb_address varchar(40) binary NOT NULL default '',
175 ipb_user int(8) unsigned NOT NULL default '0',
176 ipb_by int(8) unsigned NOT NULL default '0',
177 ipb_reason tinyblob NOT NULL default '',
178 ipb_timestamp char(14) binary NOT NULL default '',
179 ipb_auto tinyint(1) NOT NULL default '0',
180 ipb_expiry char(14) binary NOT NULL default '',
181
182 PRIMARY KEY ipb_id (ipb_id),
183 INDEX ipb_address (ipb_address),
184 INDEX ipb_user (ipb_user)
185 );
186
187 CREATE TABLE image (
188 img_name varchar(255) binary NOT NULL default '',
189 img_size int(8) unsigned NOT NULL default '0',
190 img_description tinyblob NOT NULL default '',
191 img_user int(5) unsigned NOT NULL default '0',
192 img_user_text varchar(255) binary NOT NULL default '',
193 img_timestamp char(14) binary NOT NULL default '',
194 PRIMARY KEY img_name (img_name),
195 INDEX img_size (img_size),
196 INDEX img_timestamp (img_timestamp)
197 );
198
199 CREATE TABLE oldimage (
200 oi_name varchar(255) binary NOT NULL default '',
201 oi_archive_name varchar(255) binary NOT NULL default '',
202 oi_size int(8) unsigned NOT NULL default 0,
203 oi_description tinyblob NOT NULL default '',
204 oi_user int(5) unsigned NOT NULL default '0',
205 oi_user_text varchar(255) binary NOT NULL default '',
206 oi_timestamp char(14) binary NOT NULL default '',
207 INDEX oi_name (oi_name(10))
208 );
209
210 CREATE TABLE recentchanges (
211 rc_id int(8) NOT NULL auto_increment,
212 rc_timestamp varchar(14) binary NOT NULL default '',
213 rc_cur_time varchar(14) binary NOT NULL default '',
214 rc_user int(10) unsigned NOT NULL default '0',
215 rc_user_text varchar(255) binary NOT NULL default '',
216 rc_namespace tinyint(3) NOT NULL default '0',
217 rc_title varchar(255) binary NOT NULL default '',
218 rc_comment varchar(255) binary NOT NULL default '',
219 rc_minor tinyint(3) unsigned NOT NULL default '0',
220 rc_bot tinyint(3) unsigned NOT NULL default '0',
221 rc_new tinyint(3) unsigned NOT NULL default '0',
222 rc_cur_id int(10) unsigned NOT NULL default '0',
223 rc_this_oldid int(10) unsigned NOT NULL default '0',
224 rc_last_oldid int(10) unsigned NOT NULL default '0',
225 rc_type tinyint(3) unsigned NOT NULL default '0',
226 rc_moved_to_ns tinyint(3) unsigned NOT NULL default '0',
227 rc_moved_to_title varchar(255) binary NOT NULL default '',
228 rc_patrolled tinyint(3) unsigned NOT NULL default '0',
229 rc_ip char(15) NOT NULL default '',
230
231 PRIMARY KEY rc_id (rc_id),
232 INDEX rc_timestamp (rc_timestamp),
233 INDEX rc_namespace_title (rc_namespace, rc_title),
234 INDEX rc_cur_id (rc_cur_id),
235 INDEX new_name_timestamp(rc_new,rc_namespace,rc_timestamp),
236 INDEX rc_ip (rc_ip)
237 );
238
239 CREATE TABLE watchlist (
240 wl_user int(5) unsigned NOT NULL,
241 wl_namespace tinyint(2) unsigned NOT NULL default '0',
242 wl_title varchar(255) binary NOT NULL default '',
243 UNIQUE KEY (wl_user, wl_namespace, wl_title),
244 KEY namespace_title (wl_namespace,wl_title)
245 );
246
247 CREATE TABLE math (
248 math_inputhash varchar(16) NOT NULL,
249 math_outputhash varchar(16) NOT NULL,
250 math_html_conservativeness tinyint(1) NOT NULL,
251 math_html text,
252 math_mathml text,
253 UNIQUE KEY math_inputhash (math_inputhash)
254 );
255
256
257 -- Table searchindex must be MyISAM for fulltext support
258
259 CREATE TABLE searchindex (
260 si_page int(8) unsigned NOT NULL,
261 si_title varchar(255) NOT NULL default '',
262 si_text mediumtext NOT NULL default '',
263 UNIQUE KEY (si_page),
264 FULLTEXT si_title (si_title),
265 FULLTEXT si_text (si_text)
266
267 ) TYPE=MyISAM;
268
269 CREATE TABLE interwiki (
270 iw_prefix char(32) NOT NULL,
271 iw_url char(127) NOT NULL,
272 iw_local BOOL NOT NULL,
273 UNIQUE KEY iw_prefix (iw_prefix)
274 );
275
276 -- Used for caching expensive grouped queries
277 CREATE TABLE querycache (
278 qc_type char(32) NOT NULL,
279 qc_value int(5) unsigned NOT NULL default '0',
280 qc_namespace tinyint(2) unsigned NOT NULL default '0',
281 qc_title char(255) binary NOT NULL default '',
282 KEY (qc_type,qc_value)
283 );
284
285 -- For a few generic cache operations if not using Memcached
286 CREATE TABLE objectcache (
287 keyname char(255) binary not null default '',
288 value mediumblob,
289 exptime datetime,
290 unique key (keyname),
291 key (exptime)
292 );
293
294 -- For storing revision text
295 CREATE TABLE blobs (
296 blob_index char(255) binary NOT NULL default '',
297 blob_data longblob NOT NULL default '',
298 UNIQUE key blob_index (blob_index)
299 );
300
301 -- For article validation
302
303 CREATE TABLE `validate` (
304 `val_user` int(11) NOT NULL default '0',
305 `val_title` varchar(255) binary NOT NULL default '',
306 `val_timestamp` varchar(14) binary NOT NULL default '',
307 `val_type` int(10) unsigned NOT NULL default '0',
308 `val_value` int(11) default '0',
309 `val_comment` varchar(255) NOT NULL default '',
310 KEY `val_user` (`val_user`,`val_title`,`val_timestamp`)
311 );
312
313
314 CREATE TABLE logging (
315 -- Symbolic keys for the general log type and the action type
316 -- within the log. The output format will be controlled by the
317 -- action field, but only the type controls categorization.
318 log_type char(10) NOT NULL default '',
319 log_action char(10) NOT NULL default '',
320
321 -- Timestamp. Duh.
322 log_timestamp char(14) NOT NULL default '19700101000000',
323
324 -- The user who performed this action; key to user_id
325 log_user int unsigned NOT NULL default 0,
326
327 -- Key to the page affected. Where a user is the target,
328 -- this will point to the user page.
329 log_namespace tinyint unsigned NOT NULL default 0,
330 log_title varchar(255) NOT NULL default '',
331
332 -- Freeform text. Interpreted as edit history comments.
333 log_comment varchar(255) NOT NULL default '',
334
335 KEY type_time (log_type, log_timestamp),
336 KEY user_time (log_user, log_timestamp),
337 KEY page_time (log_namespace, log_title, log_timestamp)
338 );