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