Remove over/underescaping detected in Special:UserRights
[lhc/web/wiklou.git] / maintenance / 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
5 -- This is a shared schema file used for both MySQL and SQLite installs.
6
7 --
8 -- General notes:
9 --
10 -- If possible, create tables as InnoDB to benefit from the
11 -- superior resiliency against crashes and ability to read
12 -- during writes (and write during reads!)
13 --
14 -- Only the 'searchindex' table requires MyISAM due to the
15 -- requirement for fulltext index support, which is missing
16 -- from InnoDB.
17 --
18 --
19 -- The MySQL table backend for MediaWiki currently uses
20 -- 14-character BINARY or VARBINARY fields to store timestamps.
21 -- The format is YYYYMMDDHHMMSS, which is derived from the
22 -- text format of MySQL's TIMESTAMP fields.
23 --
24 -- Historically TIMESTAMP fields were used, but abandoned
25 -- in early 2002 after a lot of trouble with the fields
26 -- auto-updating.
27 --
28 -- The Postgres backend uses TIMESTAMPTZ fields for timestamps,
29 -- and we will migrate the MySQL definitions at some point as
30 -- well.
31 --
32 --
33 -- The /*_*/ comments in this and other files are
34 -- replaced with the defined table prefix by the installer
35 -- and updater scripts. If you are installing or running
36 -- updates manually, you will need to manually insert the
37 -- table prefix if any when running these scripts.
38 --
39
40
41 --
42 -- The user table contains basic account information,
43 -- authentication keys, etc.
44 --
45 -- Some multi-wiki sites may share a single central user table
46 -- between separate wikis using the $wgSharedDB setting.
47 --
48 -- Note that when a external authentication plugin is used,
49 -- user table entries still need to be created to store
50 -- preferences and to key tracking information in the other
51 -- tables.
52 --
53 CREATE TABLE /*_*/user (
54 user_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
55
56 -- Usernames must be unique, must not be in the form of
57 -- an IP address. _Shouldn't_ allow slashes or case
58 -- conflicts. Spaces are allowed, and are _not_ converted
59 -- to underscores like titles. See the User::newFromName() for
60 -- the specific tests that usernames have to pass.
61 user_name varchar(255) binary NOT NULL default '',
62
63 -- Optional 'real name' to be displayed in credit listings
64 user_real_name varchar(255) binary NOT NULL default '',
65
66 -- Password hashes, see User::crypt() and User::comparePasswords()
67 -- in User.php for the algorithm
68 user_password tinyblob NOT NULL,
69
70 -- When using 'mail me a new password', a random
71 -- password is generated and the hash stored here.
72 -- The previous password is left in place until
73 -- someone actually logs in with the new password,
74 -- at which point the hash is moved to user_password
75 -- and the old password is invalidated.
76 user_newpassword tinyblob NOT NULL,
77
78 -- Timestamp of the last time when a new password was
79 -- sent, for throttling and expiring purposes
80 -- Emailed passwords will expire $wgNewPasswordExpiry
81 -- (a week) after being set. If user_newpass_time is NULL
82 -- (eg. created by mail) it doesn't expire.
83 user_newpass_time binary(14),
84
85 -- Note: email should be restricted, not public info.
86 -- Same with passwords.
87 user_email tinytext NOT NULL,
88
89 -- If the browser sends an If-Modified-Since header, a 304 response is
90 -- suppressed if the value in this field for the current user is later than
91 -- the value in the IMS header. That is, this field is an invalidation timestamp
92 -- for the browser cache of logged-in users. Among other things, it is used
93 -- to prevent pages generated for a previously logged in user from being
94 -- displayed after a session expiry followed by a fresh login.
95 user_touched binary(14) NOT NULL default '',
96
97 -- A pseudorandomly generated value that is stored in
98 -- a cookie when the "remember password" feature is
99 -- used (previously, a hash of the password was used, but
100 -- this was vulnerable to cookie-stealing attacks)
101 user_token binary(32) NOT NULL default '',
102
103 -- Initially NULL; when a user's e-mail address has been
104 -- validated by returning with a mailed token, this is
105 -- set to the current timestamp.
106 user_email_authenticated binary(14),
107
108 -- Randomly generated token created when the e-mail address
109 -- is set and a confirmation test mail sent.
110 user_email_token binary(32),
111
112 -- Expiration date for the user_email_token
113 user_email_token_expires binary(14),
114
115 -- Timestamp of account registration.
116 -- Accounts predating this schema addition may contain NULL.
117 user_registration binary(14),
118
119 -- Count of edits and edit-like actions.
120 --
121 -- *NOT* intended to be an accurate copy of COUNT(*) WHERE rev_user=user_id
122 -- May contain NULL for old accounts if batch-update scripts haven't been
123 -- run, as well as listing deleted edits and other myriad ways it could be
124 -- out of sync.
125 --
126 -- Meant primarily for heuristic checks to give an impression of whether
127 -- the account has been used much.
128 --
129 user_editcount int,
130
131 -- Expiration date for user password. Use $user->expirePassword()
132 -- to force a password reset.
133 user_password_expires varbinary(14) DEFAULT NULL
134
135 ) /*$wgDBTableOptions*/;
136
137 CREATE UNIQUE INDEX /*i*/user_name ON /*_*/user (user_name);
138 CREATE INDEX /*i*/user_email_token ON /*_*/user (user_email_token);
139 CREATE INDEX /*i*/user_email ON /*_*/user (user_email(50));
140
141
142 --
143 -- User permissions have been broken out to a separate table;
144 -- this allows sites with a shared user table to have different
145 -- permissions assigned to a user in each project.
146 --
147 -- This table replaces the old user_rights field which used a
148 -- comma-separated blob.
149 --
150 CREATE TABLE /*_*/user_groups (
151 -- Key to user_id
152 ug_user int unsigned NOT NULL default 0,
153
154 -- Group names are short symbolic string keys.
155 -- The set of group names is open-ended, though in practice
156 -- only some predefined ones are likely to be used.
157 --
158 -- At runtime $wgGroupPermissions will associate group keys
159 -- with particular permissions. A user will have the combined
160 -- permissions of any group they're explicitly in, plus
161 -- the implicit '*' and 'user' groups.
162 ug_group varbinary(255) NOT NULL default ''
163 ) /*$wgDBTableOptions*/;
164
165 CREATE UNIQUE INDEX /*i*/ug_user_group ON /*_*/user_groups (ug_user,ug_group);
166 CREATE INDEX /*i*/ug_group ON /*_*/user_groups (ug_group);
167
168 -- Stores the groups the user has once belonged to.
169 -- The user may still belong to these groups (check user_groups).
170 -- Users are not autopromoted to groups from which they were removed.
171 CREATE TABLE /*_*/user_former_groups (
172 -- Key to user_id
173 ufg_user int unsigned NOT NULL default 0,
174 ufg_group varbinary(255) NOT NULL default ''
175 ) /*$wgDBTableOptions*/;
176
177 CREATE UNIQUE INDEX /*i*/ufg_user_group ON /*_*/user_former_groups (ufg_user,ufg_group);
178
179 --
180 -- Stores notifications of user talk page changes, for the display
181 -- of the "you have new messages" box
182 --
183 CREATE TABLE /*_*/user_newtalk (
184 -- Key to user.user_id
185 user_id int NOT NULL default 0,
186 -- If the user is an anonymous user their IP address is stored here
187 -- since the user_id of 0 is ambiguous
188 user_ip varbinary(40) NOT NULL default '',
189 -- The highest timestamp of revisions of the talk page viewed
190 -- by this user
191 user_last_timestamp varbinary(14) NULL default NULL
192 ) /*$wgDBTableOptions*/;
193
194 -- Indexes renamed for SQLite in 1.14
195 CREATE INDEX /*i*/un_user_id ON /*_*/user_newtalk (user_id);
196 CREATE INDEX /*i*/un_user_ip ON /*_*/user_newtalk (user_ip);
197
198
199 --
200 -- User preferences and perhaps other fun stuff. :)
201 -- Replaces the old user.user_options blob, with a couple nice properties:
202 --
203 -- 1) We only store non-default settings, so changes to the defauls
204 -- are now reflected for everybody, not just new accounts.
205 -- 2) We can more easily do bulk lookups, statistics, or modifications of
206 -- saved options since it's a sane table structure.
207 --
208 CREATE TABLE /*_*/user_properties (
209 -- Foreign key to user.user_id
210 up_user int NOT NULL,
211
212 -- Name of the option being saved. This is indexed for bulk lookup.
213 up_property varbinary(255) NOT NULL,
214
215 -- Property value as a string.
216 up_value blob
217 ) /*$wgDBTableOptions*/;
218
219 CREATE UNIQUE INDEX /*i*/user_properties_user_property ON /*_*/user_properties (up_user,up_property);
220 CREATE INDEX /*i*/user_properties_property ON /*_*/user_properties (up_property);
221
222 --
223 -- Core of the wiki: each page has an entry here which identifies
224 -- it by title and contains some essential metadata.
225 --
226 CREATE TABLE /*_*/page (
227 -- Unique identifier number. The page_id will be preserved across
228 -- edits and rename operations, but not deletions and recreations.
229 page_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
230
231 -- A page name is broken into a namespace and a title.
232 -- The namespace keys are UI-language-independent constants,
233 -- defined in includes/Defines.php
234 page_namespace int NOT NULL,
235
236 -- The rest of the title, as text.
237 -- Spaces are transformed into underscores in title storage.
238 page_title varchar(255) binary NOT NULL,
239
240 -- Comma-separated set of permission keys indicating who
241 -- can move or edit the page.
242 page_restrictions tinyblob NOT NULL,
243
244 -- Number of times this page has been viewed.
245 page_counter bigint unsigned NOT NULL default 0,
246
247 -- 1 indicates the article is a redirect.
248 page_is_redirect tinyint unsigned NOT NULL default 0,
249
250 -- 1 indicates this is a new entry, with only one edit.
251 -- Not all pages with one edit are new pages.
252 page_is_new tinyint unsigned NOT NULL default 0,
253
254 -- Random value between 0 and 1, used for Special:Randompage
255 page_random real unsigned NOT NULL,
256
257 -- This timestamp is updated whenever the page changes in
258 -- a way requiring it to be re-rendered, invalidating caches.
259 -- Aside from editing this includes permission changes,
260 -- creation or deletion of linked pages, and alteration
261 -- of contained templates.
262 page_touched binary(14) NOT NULL default '',
263
264 -- This timestamp is updated whenever a page is re-parsed and
265 -- it has all the link tracking tables updated for it. This is
266 -- useful for de-duplicating expensive backlink update jobs.
267 page_links_updated varbinary(14) NULL default NULL,
268
269 -- Handy key to revision.rev_id of the current revision.
270 -- This may be 0 during page creation, but that shouldn't
271 -- happen outside of a transaction... hopefully.
272 page_latest int unsigned NOT NULL,
273
274 -- Uncompressed length in bytes of the page's current source text.
275 page_len int unsigned NOT NULL,
276
277 -- content model, see CONTENT_MODEL_XXX constants
278 page_content_model varbinary(32) DEFAULT NULL,
279
280 -- Page content language
281 page_lang varbinary(35) DEFAULT NULL
282 ) /*$wgDBTableOptions*/;
283
284 CREATE UNIQUE INDEX /*i*/name_title ON /*_*/page (page_namespace,page_title);
285 CREATE INDEX /*i*/page_random ON /*_*/page (page_random);
286 CREATE INDEX /*i*/page_len ON /*_*/page (page_len);
287 CREATE INDEX /*i*/page_redirect_namespace_len ON /*_*/page (page_is_redirect, page_namespace, page_len);
288
289 --
290 -- Every edit of a page creates also a revision row.
291 -- This stores metadata about the revision, and a reference
292 -- to the text storage backend.
293 --
294 CREATE TABLE /*_*/revision (
295 -- Unique ID to identify each revision
296 rev_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
297
298 -- Key to page_id. This should _never_ be invalid.
299 rev_page int unsigned NOT NULL,
300
301 -- Key to text.old_id, where the actual bulk text is stored.
302 -- It's possible for multiple revisions to use the same text,
303 -- for instance revisions where only metadata is altered
304 -- or a rollback to a previous version.
305 rev_text_id int unsigned NOT NULL,
306
307 -- Text comment summarizing the change.
308 -- This text is shown in the history and other changes lists,
309 -- rendered in a subset of wiki markup by Linker::formatComment()
310 rev_comment tinyblob NOT NULL,
311
312 -- Key to user.user_id of the user who made this edit.
313 -- Stores 0 for anonymous edits and for some mass imports.
314 rev_user int unsigned NOT NULL default 0,
315
316 -- Text username or IP address of the editor.
317 rev_user_text varchar(255) binary NOT NULL default '',
318
319 -- Timestamp of when revision was created
320 rev_timestamp binary(14) NOT NULL default '',
321
322 -- Records whether the user marked the 'minor edit' checkbox.
323 -- Many automated edits are marked as minor.
324 rev_minor_edit tinyint unsigned NOT NULL default 0,
325
326 -- Restrictions on who can access this revision
327 rev_deleted tinyint unsigned NOT NULL default 0,
328
329 -- Length of this revision in bytes
330 rev_len int unsigned,
331
332 -- Key to revision.rev_id
333 -- This field is used to add support for a tree structure (The Adjacency List Model)
334 rev_parent_id int unsigned default NULL,
335
336 -- SHA-1 text content hash in base-36
337 rev_sha1 varbinary(32) NOT NULL default '',
338
339 -- content model, see CONTENT_MODEL_XXX constants
340 rev_content_model varbinary(32) DEFAULT NULL,
341
342 -- content format, see CONTENT_FORMAT_XXX constants
343 rev_content_format varbinary(64) DEFAULT NULL
344
345 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
346 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
347
348 CREATE UNIQUE INDEX /*i*/rev_page_id ON /*_*/revision (rev_page, rev_id);
349 CREATE INDEX /*i*/rev_timestamp ON /*_*/revision (rev_timestamp);
350 CREATE INDEX /*i*/page_timestamp ON /*_*/revision (rev_page,rev_timestamp);
351 CREATE INDEX /*i*/user_timestamp ON /*_*/revision (rev_user,rev_timestamp);
352 CREATE INDEX /*i*/usertext_timestamp ON /*_*/revision (rev_user_text,rev_timestamp);
353 CREATE INDEX /*i*/page_user_timestamp ON /*_*/revision (rev_page,rev_user,rev_timestamp);
354
355 --
356 -- Holds text of individual page revisions.
357 --
358 -- Field names are a holdover from the 'old' revisions table in
359 -- MediaWiki 1.4 and earlier: an upgrade will transform that
360 -- table into the 'text' table to minimize unnecessary churning
361 -- and downtime. If upgrading, the other fields will be left unused.
362 --
363 CREATE TABLE /*_*/text (
364 -- Unique text storage key number.
365 -- Note that the 'oldid' parameter used in URLs does *not*
366 -- refer to this number anymore, but to rev_id.
367 --
368 -- revision.rev_text_id is a key to this column
369 old_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
370
371 -- Depending on the contents of the old_flags field, the text
372 -- may be convenient plain text, or it may be funkily encoded.
373 old_text mediumblob NOT NULL,
374
375 -- Comma-separated list of flags:
376 -- gzip: text is compressed with PHP's gzdeflate() function.
377 -- utf-8: text was stored as UTF-8.
378 -- If $wgLegacyEncoding option is on, rows *without* this flag
379 -- will be converted to UTF-8 transparently at load time. Note
380 -- that due to a bug in a maintenance script, this flag may
381 -- have been stored as 'utf8' in some cases (T18841).
382 -- object: text field contained a serialized PHP object.
383 -- The object either contains multiple versions compressed
384 -- together to achieve a better compression ratio, or it refers
385 -- to another row where the text can be found.
386 -- external: text was stored in an external location specified by old_text.
387 -- Any additional flags apply to the data stored at that URL, not
388 -- the URL itself. The 'object' flag is *not* set for URLs of the
389 -- form 'DB://cluster/id/itemid', because the external storage
390 -- system itself decompresses these.
391 old_flags tinyblob NOT NULL
392 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=10240;
393 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
394
395
396 --
397 -- Holding area for deleted articles, which may be viewed
398 -- or restored by admins through the Special:Undelete interface.
399 -- The fields generally correspond to the page, revision, and text
400 -- fields, with several caveats.
401 --
402 CREATE TABLE /*_*/archive (
403 -- Primary key
404 ar_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
405 ar_namespace int NOT NULL default 0,
406 ar_title varchar(255) binary NOT NULL default '',
407
408 -- Newly deleted pages will not store text in this table,
409 -- but will reference the separately existing text rows.
410 -- This field is retained for backwards compatibility,
411 -- so old archived pages will remain accessible after
412 -- upgrading from 1.4 to 1.5.
413 -- Text may be gzipped or otherwise funky.
414 ar_text mediumblob NOT NULL,
415
416 -- Basic revision stuff...
417 ar_comment tinyblob NOT NULL,
418 ar_user int unsigned NOT NULL default 0,
419 ar_user_text varchar(255) binary NOT NULL,
420 ar_timestamp binary(14) NOT NULL default '',
421 ar_minor_edit tinyint NOT NULL default 0,
422
423 -- See ar_text note.
424 ar_flags tinyblob NOT NULL,
425
426 -- When revisions are deleted, their unique rev_id is stored
427 -- here so it can be retained after undeletion. This is necessary
428 -- to retain permalinks to given revisions after accidental delete
429 -- cycles or messy operations like history merges.
430 --
431 -- Old entries from 1.4 will be NULL here, and a new rev_id will
432 -- be created on undeletion for those revisions.
433 ar_rev_id int unsigned,
434
435 -- For newly deleted revisions, this is the text.old_id key to the
436 -- actual stored text. To avoid breaking the block-compression scheme
437 -- and otherwise making storage changes harder, the actual text is
438 -- *not* deleted from the text table, merely hidden by removal of the
439 -- page and revision entries.
440 --
441 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
442 -- ar_text and ar_flags fields will be used to create a new text
443 -- row upon undeletion.
444 ar_text_id int unsigned,
445
446 -- rev_deleted for archives
447 ar_deleted tinyint unsigned NOT NULL default 0,
448
449 -- Length of this revision in bytes
450 ar_len int unsigned,
451
452 -- Reference to page_id. Useful for sysadmin fixing of large pages
453 -- merged together in the archives, or for cleanly restoring a page
454 -- at its original ID number if possible.
455 --
456 -- Will be NULL for pages deleted prior to 1.11.
457 ar_page_id int unsigned,
458
459 -- Original previous revision
460 ar_parent_id int unsigned default NULL,
461
462 -- SHA-1 text content hash in base-36
463 ar_sha1 varbinary(32) NOT NULL default '',
464
465 -- content model, see CONTENT_MODEL_XXX constants
466 ar_content_model varbinary(32) DEFAULT NULL,
467
468 -- content format, see CONTENT_FORMAT_XXX constants
469 ar_content_format varbinary(64) DEFAULT NULL
470 ) /*$wgDBTableOptions*/;
471
472 CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp);
473 CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp);
474 CREATE INDEX /*i*/ar_revid ON /*_*/archive (ar_rev_id);
475
476
477 --
478 -- Track page-to-page hyperlinks within the wiki.
479 --
480 CREATE TABLE /*_*/pagelinks (
481 -- Key to the page_id of the page containing the link.
482 pl_from int unsigned NOT NULL default 0,
483 -- Namespace for this page
484 pl_from_namespace int NOT NULL default 0,
485
486 -- Key to page_namespace/page_title of the target page.
487 -- The target page may or may not exist, and due to renames
488 -- and deletions may refer to different page records as time
489 -- goes by.
490 pl_namespace int NOT NULL default 0,
491 pl_title varchar(255) binary NOT NULL default ''
492 ) /*$wgDBTableOptions*/;
493
494 CREATE UNIQUE INDEX /*i*/pl_from ON /*_*/pagelinks (pl_from,pl_namespace,pl_title);
495 CREATE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from);
496 CREATE INDEX /*i*/pl_backlinks_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from_namespace,pl_from);
497
498
499 --
500 -- Track template inclusions.
501 --
502 CREATE TABLE /*_*/templatelinks (
503 -- Key to the page_id of the page containing the link.
504 tl_from int unsigned NOT NULL default 0,
505 -- Namespace for this page
506 tl_from_namespace int NOT NULL default 0,
507
508 -- Key to page_namespace/page_title of the target page.
509 -- The target page may or may not exist, and due to renames
510 -- and deletions may refer to different page records as time
511 -- goes by.
512 tl_namespace int NOT NULL default 0,
513 tl_title varchar(255) binary NOT NULL default ''
514 ) /*$wgDBTableOptions*/;
515
516 CREATE UNIQUE INDEX /*i*/tl_from ON /*_*/templatelinks (tl_from,tl_namespace,tl_title);
517 CREATE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from);
518 CREATE INDEX /*i*/tl_backlinks_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from_namespace,tl_from);
519
520
521 --
522 -- Track links to images *used inline*
523 -- We don't distinguish live from broken links here, so
524 -- they do not need to be changed on upload/removal.
525 --
526 CREATE TABLE /*_*/imagelinks (
527 -- Key to page_id of the page containing the image / media link.
528 il_from int unsigned NOT NULL default 0,
529 -- Namespace for this page
530 il_from_namespace int NOT NULL default 0,
531
532 -- Filename of target image.
533 -- This is also the page_title of the file's description page;
534 -- all such pages are in namespace 6 (NS_FILE).
535 il_to varchar(255) binary NOT NULL default ''
536 ) /*$wgDBTableOptions*/;
537
538 CREATE UNIQUE INDEX /*i*/il_from ON /*_*/imagelinks (il_from,il_to);
539 CREATE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from);
540 CREATE INDEX /*i*/il_backlinks_namespace ON /*_*/imagelinks (il_to,il_from_namespace,il_from);
541
542
543 --
544 -- Track category inclusions *used inline*
545 -- This tracks a single level of category membership
546 --
547 CREATE TABLE /*_*/categorylinks (
548 -- Key to page_id of the page defined as a category member.
549 cl_from int unsigned NOT NULL default 0,
550
551 -- Name of the category.
552 -- This is also the page_title of the category's description page;
553 -- all such pages are in namespace 14 (NS_CATEGORY).
554 cl_to varchar(255) binary NOT NULL default '',
555
556 -- A binary string obtained by applying a sortkey generation algorithm
557 -- (Collation::getSortKey()) to page_title, or cl_sortkey_prefix . "\n"
558 -- . page_title if cl_sortkey_prefix is nonempty.
559 cl_sortkey varbinary(230) NOT NULL default '',
560
561 -- A prefix for the raw sortkey manually specified by the user, either via
562 -- [[Category:Foo|prefix]] or {{defaultsort:prefix}}. If nonempty, it's
563 -- concatenated with a line break followed by the page title before the sortkey
564 -- conversion algorithm is run. We store this so that we can update
565 -- collations without reparsing all pages.
566 -- Note: If you change the length of this field, you also need to change
567 -- code in LinksUpdate.php. See bug 25254.
568 cl_sortkey_prefix varchar(255) binary NOT NULL default '',
569
570 -- This isn't really used at present. Provided for an optional
571 -- sorting method by approximate addition time.
572 cl_timestamp timestamp NOT NULL,
573
574 -- Stores $wgCategoryCollation at the time cl_sortkey was generated. This
575 -- can be used to install new collation versions, tracking which rows are not
576 -- yet updated. '' means no collation, this is a legacy row that needs to be
577 -- updated by updateCollation.php. In the future, it might be possible to
578 -- specify different collations per category.
579 cl_collation varbinary(32) NOT NULL default '',
580
581 -- Stores whether cl_from is a category, file, or other page, so we can
582 -- paginate the three categories separately. This never has to be updated
583 -- after the page is created, since none of these page types can be moved to
584 -- any other.
585 cl_type ENUM('page', 'subcat', 'file') NOT NULL default 'page'
586 ) /*$wgDBTableOptions*/;
587
588 CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to);
589
590 -- We always sort within a given category, and within a given type. FIXME:
591 -- Formerly this index didn't cover cl_type (since that didn't exist), so old
592 -- callers won't be using an index: fix this?
593 CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_type,cl_sortkey,cl_from);
594
595 -- Used by the API (and some extensions)
596 CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);
597
598 -- FIXME: Not used, delete this
599 CREATE INDEX /*i*/cl_collation ON /*_*/categorylinks (cl_collation);
600
601 --
602 -- Track all existing categories. Something is a category if 1) it has an en-
603 -- try somewhere in categorylinks, or 2) it once did. Categories might not
604 -- have corresponding pages, so they need to be tracked separately.
605 --
606 CREATE TABLE /*_*/category (
607 -- Primary key
608 cat_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
609
610 -- Name of the category, in the same form as page_title (with underscores).
611 -- If there is a category page corresponding to this category, by definition,
612 -- it has this name (in the Category namespace).
613 cat_title varchar(255) binary NOT NULL,
614
615 -- The numbers of member pages (including categories and media), subcatego-
616 -- ries, and Image: namespace members, respectively. These are signed to
617 -- make underflow more obvious. We make the first number include the second
618 -- two for better sorting: subtracting for display is easy, adding for order-
619 -- ing is not.
620 cat_pages int signed NOT NULL default 0,
621 cat_subcats int signed NOT NULL default 0,
622 cat_files int signed NOT NULL default 0
623 ) /*$wgDBTableOptions*/;
624
625 CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);
626
627 -- For Special:Mostlinkedcategories
628 CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);
629
630
631 --
632 -- Track links to external URLs
633 --
634 CREATE TABLE /*_*/externallinks (
635 -- Primary key
636 el_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
637
638 -- page_id of the referring page
639 el_from int unsigned NOT NULL default 0,
640
641 -- The URL
642 el_to blob NOT NULL,
643
644 -- In the case of HTTP URLs, this is the URL with any username or password
645 -- removed, and with the labels in the hostname reversed and converted to
646 -- lower case. An extra dot is added to allow for matching of either
647 -- example.com or *.example.com in a single scan.
648 -- Example:
649 -- http://user:password@sub.example.com/page.html
650 -- becomes
651 -- http://com.example.sub./page.html
652 -- which allows for fast searching for all pages under example.com with the
653 -- clause:
654 -- WHERE el_index LIKE 'http://com.example.%'
655 el_index blob NOT NULL
656 ) /*$wgDBTableOptions*/;
657
658 CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from, el_to(40));
659 CREATE INDEX /*i*/el_to ON /*_*/externallinks (el_to(60), el_from);
660 CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index(60));
661
662 --
663 -- Track interlanguage links
664 --
665 CREATE TABLE /*_*/langlinks (
666 -- page_id of the referring page
667 ll_from int unsigned NOT NULL default 0,
668
669 -- Language code of the target
670 ll_lang varbinary(20) NOT NULL default '',
671
672 -- Title of the target, including namespace
673 ll_title varchar(255) binary NOT NULL default ''
674 ) /*$wgDBTableOptions*/;
675
676 CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang);
677 CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);
678
679
680 --
681 -- Track inline interwiki links
682 --
683 CREATE TABLE /*_*/iwlinks (
684 -- page_id of the referring page
685 iwl_from int unsigned NOT NULL default 0,
686
687 -- Interwiki prefix code of the target
688 iwl_prefix varbinary(20) NOT NULL default '',
689
690 -- Title of the target, including namespace
691 iwl_title varchar(255) binary NOT NULL default ''
692 ) /*$wgDBTableOptions*/;
693
694 CREATE UNIQUE INDEX /*i*/iwl_from ON /*_*/iwlinks (iwl_from, iwl_prefix, iwl_title);
695 CREATE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from);
696 CREATE INDEX /*i*/iwl_prefix_from_title ON /*_*/iwlinks (iwl_prefix, iwl_from, iwl_title);
697
698
699 --
700 -- Contains a single row with some aggregate info
701 -- on the state of the site.
702 --
703 CREATE TABLE /*_*/site_stats (
704 -- The single row should contain 1 here.
705 ss_row_id int unsigned NOT NULL,
706
707 -- Total number of page views, if hit counters are enabled.
708 ss_total_views bigint unsigned default 0,
709
710 -- Total number of edits performed.
711 ss_total_edits bigint unsigned default 0,
712
713 -- An approximate count of pages matching the following criteria:
714 -- * in namespace 0
715 -- * not a redirect
716 -- * contains the text '[['
717 -- See Article::isCountable() in includes/Article.php
718 ss_good_articles bigint unsigned default 0,
719
720 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
721 ss_total_pages bigint default '-1',
722
723 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
724 ss_users bigint default '-1',
725
726 -- Number of users that still edit
727 ss_active_users bigint default '-1',
728
729 -- Number of images, equivalent to SELECT COUNT(*) FROM image
730 ss_images int default 0
731 ) /*$wgDBTableOptions*/;
732
733 -- Pointless index to assuage developer superstitions
734 CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id);
735
736
737 --
738 -- Stores an ID for every time any article is visited;
739 -- depending on $wgHitcounterUpdateFreq, it is
740 -- periodically cleared and the page_counter column
741 -- in the page table updated for all the articles
742 -- that have been visited.)
743 --
744 CREATE TABLE /*_*/hitcounter (
745 hc_id int unsigned NOT NULL
746 ) ENGINE=MEMORY MAX_ROWS=25000;
747
748
749 --
750 -- The internet is full of jerks, alas. Sometimes it's handy
751 -- to block a vandal or troll account.
752 --
753 CREATE TABLE /*_*/ipblocks (
754 -- Primary key, introduced for privacy.
755 ipb_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
756
757 -- Blocked IP address in dotted-quad form or user name.
758 ipb_address tinyblob NOT NULL,
759
760 -- Blocked user ID or 0 for IP blocks.
761 ipb_user int unsigned NOT NULL default 0,
762
763 -- User ID who made the block.
764 ipb_by int unsigned NOT NULL default 0,
765
766 -- User name of blocker
767 ipb_by_text varchar(255) binary NOT NULL default '',
768
769 -- Text comment made by blocker.
770 ipb_reason tinyblob NOT NULL,
771
772 -- Creation (or refresh) date in standard YMDHMS form.
773 -- IP blocks expire automatically.
774 ipb_timestamp binary(14) NOT NULL default '',
775
776 -- Indicates that the IP address was banned because a banned
777 -- user accessed a page through it. If this is 1, ipb_address
778 -- will be hidden, and the block identified by block ID number.
779 ipb_auto bool NOT NULL default 0,
780
781 -- If set to 1, block applies only to logged-out users
782 ipb_anon_only bool NOT NULL default 0,
783
784 -- Block prevents account creation from matching IP addresses
785 ipb_create_account bool NOT NULL default 1,
786
787 -- Block triggers autoblocks
788 ipb_enable_autoblock bool NOT NULL default '1',
789
790 -- Time at which the block will expire.
791 -- May be "infinity"
792 ipb_expiry varbinary(14) NOT NULL default '',
793
794 -- Start and end of an address range, in hexadecimal
795 -- Size chosen to allow IPv6
796 -- FIXME: these fields were originally blank for single-IP blocks,
797 -- but now they are populated. No migration was ever done. They
798 -- should be fixed to be blank again for such blocks (bug 49504).
799 ipb_range_start tinyblob NOT NULL,
800 ipb_range_end tinyblob NOT NULL,
801
802 -- Flag for entries hidden from users and Sysops
803 ipb_deleted bool NOT NULL default 0,
804
805 -- Block prevents user from accessing Special:Emailuser
806 ipb_block_email bool NOT NULL default 0,
807
808 -- Block allows user to edit their own talk page
809 ipb_allow_usertalk bool NOT NULL default 0,
810
811 -- ID of the block that caused this block to exist
812 -- Autoblocks set this to the original block
813 -- so that the original block being deleted also
814 -- deletes the autoblocks
815 ipb_parent_block_id int default NULL
816
817 ) /*$wgDBTableOptions*/;
818
819 -- Unique index to support "user already blocked" messages
820 -- Any new options which prevent collisions should be included
821 CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only);
822
823 CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
824 CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start(8), ipb_range_end(8));
825 CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
826 CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
827 CREATE INDEX /*i*/ipb_parent_block_id ON /*_*/ipblocks (ipb_parent_block_id);
828
829
830 --
831 -- Uploaded images and other files.
832 --
833 CREATE TABLE /*_*/image (
834 -- Filename.
835 -- This is also the title of the associated description page,
836 -- which will be in namespace 6 (NS_FILE).
837 img_name varchar(255) binary NOT NULL default '' PRIMARY KEY,
838
839 -- File size in bytes.
840 img_size int unsigned NOT NULL default 0,
841
842 -- For images, size in pixels.
843 img_width int NOT NULL default 0,
844 img_height int NOT NULL default 0,
845
846 -- Extracted Exif metadata stored as a serialized PHP array.
847 img_metadata mediumblob NOT NULL,
848
849 -- For images, bits per pixel if known.
850 img_bits int NOT NULL default 0,
851
852 -- Media type as defined by the MEDIATYPE_xxx constants
853 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
854
855 -- major part of a MIME media type as defined by IANA
856 -- see http://www.iana.org/assignments/media-types/
857 -- for "chemical" cf. http://dx.doi.org/10.1021/ci9803233 by the ACS
858 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown",
859
860 -- minor part of a MIME media type as defined by IANA
861 -- the minor parts are not required to adher to any standard
862 -- but should be consistent throughout the database
863 -- see http://www.iana.org/assignments/media-types/
864 img_minor_mime varbinary(100) NOT NULL default "unknown",
865
866 -- Description field as entered by the uploader.
867 -- This is displayed in image upload history and logs.
868 img_description tinyblob NOT NULL,
869
870 -- user_id and user_name of uploader.
871 img_user int unsigned NOT NULL default 0,
872 img_user_text varchar(255) binary NOT NULL,
873
874 -- Time of the upload.
875 img_timestamp varbinary(14) NOT NULL default '',
876
877 -- SHA-1 content hash in base-36
878 img_sha1 varbinary(32) NOT NULL default ''
879 ) /*$wgDBTableOptions*/;
880
881 CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
882 -- Used by Special:ListFiles for sort-by-size
883 CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
884 -- Used by Special:Newimages and Special:ListFiles
885 CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
886 -- Used in API and duplicate search
887 CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1(10));
888 -- Used to get media of one type
889 CREATE INDEX /*i*/img_media_mime ON /*_*/image (img_media_type,img_major_mime,img_minor_mime);
890
891
892 --
893 -- Previous revisions of uploaded files.
894 -- Awkwardly, image rows have to be moved into
895 -- this table at re-upload time.
896 --
897 CREATE TABLE /*_*/oldimage (
898 -- Base filename: key to image.img_name
899 oi_name varchar(255) binary NOT NULL default '',
900
901 -- Filename of the archived file.
902 -- This is generally a timestamp and '!' prepended to the base name.
903 oi_archive_name varchar(255) binary NOT NULL default '',
904
905 -- Other fields as in image...
906 oi_size int unsigned NOT NULL default 0,
907 oi_width int NOT NULL default 0,
908 oi_height int NOT NULL default 0,
909 oi_bits int NOT NULL default 0,
910 oi_description tinyblob NOT NULL,
911 oi_user int unsigned NOT NULL default 0,
912 oi_user_text varchar(255) binary NOT NULL,
913 oi_timestamp binary(14) NOT NULL default '',
914
915 oi_metadata mediumblob NOT NULL,
916 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
917 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown",
918 oi_minor_mime varbinary(100) NOT NULL default "unknown",
919 oi_deleted tinyint unsigned NOT NULL default 0,
920 oi_sha1 varbinary(32) NOT NULL default ''
921 ) /*$wgDBTableOptions*/;
922
923 CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
924 CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
925 -- oi_archive_name truncated to 14 to avoid key length overflow
926 CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name(14));
927 CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1(10));
928
929
930 --
931 -- Record of deleted file data
932 --
933 CREATE TABLE /*_*/filearchive (
934 -- Unique row id
935 fa_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
936
937 -- Original base filename; key to image.img_name, page.page_title, etc
938 fa_name varchar(255) binary NOT NULL default '',
939
940 -- Filename of archived file, if an old revision
941 fa_archive_name varchar(255) binary default '',
942
943 -- Which storage bin (directory tree or object store) the file data
944 -- is stored in. Should be 'deleted' for files that have been deleted;
945 -- any other bin is not yet in use.
946 fa_storage_group varbinary(16),
947
948 -- SHA-1 of the file contents plus extension, used as a key for storage.
949 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
950 --
951 -- If NULL, the file was missing at deletion time or has been purged
952 -- from the archival storage.
953 fa_storage_key varbinary(64) default '',
954
955 -- Deletion information, if this file is deleted.
956 fa_deleted_user int,
957 fa_deleted_timestamp binary(14) default '',
958 fa_deleted_reason text,
959
960 -- Duped fields from image
961 fa_size int unsigned default 0,
962 fa_width int default 0,
963 fa_height int default 0,
964 fa_metadata mediumblob,
965 fa_bits int default 0,
966 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
967 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") default "unknown",
968 fa_minor_mime varbinary(100) default "unknown",
969 fa_description tinyblob,
970 fa_user int unsigned default 0,
971 fa_user_text varchar(255) binary,
972 fa_timestamp binary(14) default '',
973
974 -- Visibility of deleted revisions, bitfield
975 fa_deleted tinyint unsigned NOT NULL default 0,
976
977 -- sha1 hash of file content
978 fa_sha1 varbinary(32) NOT NULL default ''
979 ) /*$wgDBTableOptions*/;
980
981 -- pick out by image name
982 CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
983 -- pick out dupe files
984 CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
985 -- sort by deletion time
986 CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
987 -- sort by uploader
988 CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
989 -- find file by sha1, 10 bytes will be enough for hashes to be indexed
990 CREATE INDEX /*i*/fa_sha1 ON /*_*/filearchive (fa_sha1(10));
991
992
993 --
994 -- Store information about newly uploaded files before they're
995 -- moved into the actual filestore
996 --
997 CREATE TABLE /*_*/uploadstash (
998 us_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
999
1000 -- the user who uploaded the file.
1001 us_user int unsigned NOT NULL,
1002
1003 -- file key. this is how applications actually search for the file.
1004 -- this might go away, or become the primary key.
1005 us_key varchar(255) NOT NULL,
1006
1007 -- the original path
1008 us_orig_path varchar(255) NOT NULL,
1009
1010 -- the temporary path at which the file is actually stored
1011 us_path varchar(255) NOT NULL,
1012
1013 -- which type of upload the file came from (sometimes)
1014 us_source_type varchar(50),
1015
1016 -- the date/time on which the file was added
1017 us_timestamp varbinary(14) NOT NULL,
1018
1019 us_status varchar(50) NOT NULL,
1020
1021 -- chunk counter starts at 0, current offset is stored in us_size
1022 us_chunk_inx int unsigned NULL,
1023
1024 -- Serialized file properties from FSFile::getProps()
1025 us_props blob,
1026
1027 -- file size in bytes
1028 us_size int unsigned NOT NULL,
1029 -- this hash comes from FSFile::getSha1Base36(), and is 31 characters
1030 us_sha1 varchar(31) NOT NULL,
1031 us_mime varchar(255),
1032 -- Media type as defined by the MEDIATYPE_xxx constants, should duplicate definition in the image table
1033 us_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
1034 -- image-specific properties
1035 us_image_width int unsigned,
1036 us_image_height int unsigned,
1037 us_image_bits smallint unsigned
1038
1039 ) /*$wgDBTableOptions*/;
1040
1041 -- sometimes there's a delete for all of a user's stuff.
1042 CREATE INDEX /*i*/us_user ON /*_*/uploadstash (us_user);
1043 -- pick out files by key, enforce key uniqueness
1044 CREATE UNIQUE INDEX /*i*/us_key ON /*_*/uploadstash (us_key);
1045 -- the abandoned upload cleanup script needs this
1046 CREATE INDEX /*i*/us_timestamp ON /*_*/uploadstash (us_timestamp);
1047
1048
1049 --
1050 -- Primarily a summary table for Special:Recentchanges,
1051 -- this table contains some additional info on edits from
1052 -- the last few days, see Article::editUpdates()
1053 --
1054 CREATE TABLE /*_*/recentchanges (
1055 rc_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
1056 rc_timestamp varbinary(14) NOT NULL default '',
1057
1058 -- As in revision
1059 rc_user int unsigned NOT NULL default 0,
1060 rc_user_text varchar(255) binary NOT NULL,
1061
1062 -- When pages are renamed, their RC entries do _not_ change.
1063 rc_namespace int NOT NULL default 0,
1064 rc_title varchar(255) binary NOT NULL default '',
1065
1066 -- as in revision...
1067 rc_comment varchar(255) binary NOT NULL default '',
1068 rc_minor tinyint unsigned NOT NULL default 0,
1069
1070 -- Edits by user accounts with the 'bot' rights key are
1071 -- marked with a 1 here, and will be hidden from the
1072 -- default view.
1073 rc_bot tinyint unsigned NOT NULL default 0,
1074
1075 -- Set if this change corresponds to a page creation
1076 rc_new tinyint unsigned NOT NULL default 0,
1077
1078 -- Key to page_id (was cur_id prior to 1.5).
1079 -- This will keep links working after moves while
1080 -- retaining the at-the-time name in the changes list.
1081 rc_cur_id int unsigned NOT NULL default 0,
1082
1083 -- rev_id of the given revision
1084 rc_this_oldid int unsigned NOT NULL default 0,
1085
1086 -- rev_id of the prior revision, for generating diff links.
1087 rc_last_oldid int unsigned NOT NULL default 0,
1088
1089 -- The type of change entry (RC_EDIT,RC_NEW,RC_LOG,RC_EXTERNAL)
1090 rc_type tinyint unsigned NOT NULL default 0,
1091
1092 -- The source of the change entry (replaces rc_type)
1093 -- default of '' is temporary, needed for initial migration
1094 rc_source varchar(16) binary not null default '',
1095
1096 -- If the Recent Changes Patrol option is enabled,
1097 -- users may mark edits as having been reviewed to
1098 -- remove a warning flag on the RC list.
1099 -- A value of 1 indicates the page has been reviewed.
1100 rc_patrolled tinyint unsigned NOT NULL default 0,
1101
1102 -- Recorded IP address the edit was made from, if the
1103 -- $wgPutIPinRC option is enabled.
1104 rc_ip varbinary(40) NOT NULL default '',
1105
1106 -- Text length in characters before
1107 -- and after the edit
1108 rc_old_len int,
1109 rc_new_len int,
1110
1111 -- Visibility of recent changes items, bitfield
1112 rc_deleted tinyint unsigned NOT NULL default 0,
1113
1114 -- Value corresponding to log_id, specific log entries
1115 rc_logid int unsigned NOT NULL default 0,
1116 -- Store log type info here, or null
1117 rc_log_type varbinary(255) NULL default NULL,
1118 -- Store log action or null
1119 rc_log_action varbinary(255) NULL default NULL,
1120 -- Log params
1121 rc_params blob NULL
1122 ) /*$wgDBTableOptions*/;
1123
1124 CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
1125 CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
1126 CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
1127 CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
1128 CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
1129 CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
1130 CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);
1131
1132
1133 CREATE TABLE /*_*/watchlist (
1134 -- Key to user.user_id
1135 wl_user int unsigned NOT NULL,
1136
1137 -- Key to page_namespace/page_title
1138 -- Note that users may watch pages which do not exist yet,
1139 -- or existed in the past but have been deleted.
1140 wl_namespace int NOT NULL default 0,
1141 wl_title varchar(255) binary NOT NULL default '',
1142
1143 -- Timestamp used to send notification e-mails and show "updated since last visit" markers on
1144 -- history and recent changes / watchlist. Set to NULL when the user visits the latest revision
1145 -- of the page, which means that they should be sent an e-mail on the next change.
1146 wl_notificationtimestamp varbinary(14)
1147
1148 ) /*$wgDBTableOptions*/;
1149
1150 CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
1151 CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);
1152 CREATE INDEX /*i*/wl_user_notificationtimestamp ON /*_*/watchlist (wl_user, wl_notificationtimestamp);
1153
1154
1155 --
1156 -- When using the default MySQL search backend, page titles
1157 -- and text are munged to strip markup, do Unicode case folding,
1158 -- and prepare the result for MySQL's fulltext index.
1159 --
1160 -- This table must be MyISAM; InnoDB does not support the needed
1161 -- fulltext index.
1162 --
1163 CREATE TABLE /*_*/searchindex (
1164 -- Key to page_id
1165 si_page int unsigned NOT NULL,
1166
1167 -- Munged version of title
1168 si_title varchar(255) NOT NULL default '',
1169
1170 -- Munged version of body text
1171 si_text mediumtext NOT NULL
1172 ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
1173
1174 CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
1175 CREATE FULLTEXT INDEX /*i*/si_title ON /*_*/searchindex (si_title);
1176 CREATE FULLTEXT INDEX /*i*/si_text ON /*_*/searchindex (si_text);
1177
1178
1179 --
1180 -- Recognized interwiki link prefixes
1181 --
1182 CREATE TABLE /*_*/interwiki (
1183 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
1184 iw_prefix varchar(32) NOT NULL,
1185
1186 -- The URL of the wiki, with "$1" as a placeholder for an article name.
1187 -- Any spaces in the name will be transformed to underscores before
1188 -- insertion.
1189 iw_url blob NOT NULL,
1190
1191 -- The URL of the file api.php
1192 iw_api blob NOT NULL,
1193
1194 -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' ))
1195 iw_wikiid varchar(64) NOT NULL,
1196
1197 -- A boolean value indicating whether the wiki is in this project
1198 -- (used, for example, to detect redirect loops)
1199 iw_local bool NOT NULL,
1200
1201 -- Boolean value indicating whether interwiki transclusions are allowed.
1202 iw_trans tinyint NOT NULL default 0
1203 ) /*$wgDBTableOptions*/;
1204
1205 CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);
1206
1207
1208 --
1209 -- Used for caching expensive grouped queries
1210 --
1211 CREATE TABLE /*_*/querycache (
1212 -- A key name, generally the base name of of the special page.
1213 qc_type varbinary(32) NOT NULL,
1214
1215 -- Some sort of stored value. Sizes, counts...
1216 qc_value int unsigned NOT NULL default 0,
1217
1218 -- Target namespace+title
1219 qc_namespace int NOT NULL default 0,
1220 qc_title varchar(255) binary NOT NULL default ''
1221 ) /*$wgDBTableOptions*/;
1222
1223 CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);
1224
1225
1226 --
1227 -- For a few generic cache operations if not using Memcached
1228 --
1229 CREATE TABLE /*_*/objectcache (
1230 keyname varbinary(255) NOT NULL default '' PRIMARY KEY,
1231 value mediumblob,
1232 exptime datetime
1233 ) /*$wgDBTableOptions*/;
1234 CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);
1235
1236
1237 --
1238 -- Cache of interwiki transclusion
1239 --
1240 CREATE TABLE /*_*/transcache (
1241 tc_url varbinary(255) NOT NULL,
1242 tc_contents text,
1243 tc_time binary(14) NOT NULL
1244 ) /*$wgDBTableOptions*/;
1245
1246 CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url);
1247
1248
1249 CREATE TABLE /*_*/logging (
1250 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1251 log_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1252
1253 -- Symbolic keys for the general log type and the action type
1254 -- within the log. The output format will be controlled by the
1255 -- action field, but only the type controls categorization.
1256 log_type varbinary(32) NOT NULL default '',
1257 log_action varbinary(32) NOT NULL default '',
1258
1259 -- Timestamp. Duh.
1260 log_timestamp binary(14) NOT NULL default '19700101000000',
1261
1262 -- The user who performed this action; key to user_id
1263 log_user int unsigned NOT NULL default 0,
1264
1265 -- Name of the user who performed this action
1266 log_user_text varchar(255) binary NOT NULL default '',
1267
1268 -- Key to the page affected. Where a user is the target,
1269 -- this will point to the user page.
1270 log_namespace int NOT NULL default 0,
1271 log_title varchar(255) binary NOT NULL default '',
1272 log_page int unsigned NULL,
1273
1274 -- Freeform text. Interpreted as edit history comments.
1275 log_comment varchar(255) NOT NULL default '',
1276
1277 -- miscellaneous parameters:
1278 -- LF separated list (old system) or serialized PHP array (new system)
1279 log_params blob NOT NULL,
1280
1281 -- rev_deleted for logs
1282 log_deleted tinyint unsigned NOT NULL default 0
1283 ) /*$wgDBTableOptions*/;
1284
1285 CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
1286 CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
1287 CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
1288 CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
1289 CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp);
1290 CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp);
1291 CREATE INDEX /*i*/type_action ON /*_*/logging (log_type, log_action, log_timestamp);
1292 CREATE INDEX /*i*/log_user_text_type_time ON /*_*/logging (log_user_text, log_type, log_timestamp);
1293 CREATE INDEX /*i*/log_user_text_time ON /*_*/logging (log_user_text, log_timestamp);
1294
1295
1296 CREATE TABLE /*_*/log_search (
1297 -- The type of ID (rev ID, log ID, rev timestamp, username)
1298 ls_field varbinary(32) NOT NULL,
1299 -- The value of the ID
1300 ls_value varchar(255) NOT NULL,
1301 -- Key to log_id
1302 ls_log_id int unsigned NOT NULL default 0
1303 ) /*$wgDBTableOptions*/;
1304 CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id);
1305 CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);
1306
1307
1308 -- Jobs performed by parallel apache threads or a command-line daemon
1309 CREATE TABLE /*_*/job (
1310 job_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1311
1312 -- Command name
1313 -- Limited to 60 to prevent key length overflow
1314 job_cmd varbinary(60) NOT NULL default '',
1315
1316 -- Namespace and title to act on
1317 -- Should be 0 and '' if the command does not operate on a title
1318 job_namespace int NOT NULL,
1319 job_title varchar(255) binary NOT NULL,
1320
1321 -- Timestamp of when the job was inserted
1322 -- NULL for jobs added before addition of the timestamp
1323 job_timestamp varbinary(14) NULL default NULL,
1324
1325 -- Any other parameters to the command
1326 -- Stored as a PHP serialized array, or an empty string if there are no parameters
1327 job_params blob NOT NULL,
1328
1329 -- Random, non-unique, number used for job acquisition (for lock concurrency)
1330 job_random integer unsigned NOT NULL default 0,
1331
1332 -- The number of times this job has been locked
1333 job_attempts integer unsigned NOT NULL default 0,
1334
1335 -- Field that conveys process locks on rows via process UUIDs
1336 job_token varbinary(32) NOT NULL default '',
1337
1338 -- Timestamp when the job was locked
1339 job_token_timestamp varbinary(14) NULL default NULL,
1340
1341 -- Base 36 SHA1 of the job parameters relevant to detecting duplicates
1342 job_sha1 varbinary(32) NOT NULL default ''
1343 ) /*$wgDBTableOptions*/;
1344
1345 CREATE INDEX /*i*/job_sha1 ON /*_*/job (job_sha1);
1346 CREATE INDEX /*i*/job_cmd_token ON /*_*/job (job_cmd,job_token,job_random);
1347 CREATE INDEX /*i*/job_cmd_token_id ON /*_*/job (job_cmd,job_token,job_id);
1348 CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title, job_params(128));
1349 CREATE INDEX /*i*/job_timestamp ON /*_*/job (job_timestamp);
1350
1351
1352 -- Details of updates to cached special pages
1353 CREATE TABLE /*_*/querycache_info (
1354 -- Special page name
1355 -- Corresponds to a qc_type value
1356 qci_type varbinary(32) NOT NULL default '',
1357
1358 -- Timestamp of last update
1359 qci_timestamp binary(14) NOT NULL default '19700101000000'
1360 ) /*$wgDBTableOptions*/;
1361
1362 CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type);
1363
1364
1365 -- For each redirect, this table contains exactly one row defining its target
1366 CREATE TABLE /*_*/redirect (
1367 -- Key to the page_id of the redirect page
1368 rd_from int unsigned NOT NULL default 0 PRIMARY KEY,
1369
1370 -- Key to page_namespace/page_title of the target page.
1371 -- The target page may or may not exist, and due to renames
1372 -- and deletions may refer to different page records as time
1373 -- goes by.
1374 rd_namespace int NOT NULL default 0,
1375 rd_title varchar(255) binary NOT NULL default '',
1376 rd_interwiki varchar(32) default NULL,
1377 rd_fragment varchar(255) binary default NULL
1378 ) /*$wgDBTableOptions*/;
1379
1380 CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);
1381
1382
1383 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1384 CREATE TABLE /*_*/querycachetwo (
1385 -- A key name, generally the base name of of the special page.
1386 qcc_type varbinary(32) NOT NULL,
1387
1388 -- Some sort of stored value. Sizes, counts...
1389 qcc_value int unsigned NOT NULL default 0,
1390
1391 -- Target namespace+title
1392 qcc_namespace int NOT NULL default 0,
1393 qcc_title varchar(255) binary NOT NULL default '',
1394
1395 -- Target namespace+title2
1396 qcc_namespacetwo int NOT NULL default 0,
1397 qcc_titletwo varchar(255) binary NOT NULL default ''
1398 ) /*$wgDBTableOptions*/;
1399
1400 CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
1401 CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
1402 CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
1403
1404
1405 -- Used for storing page restrictions (i.e. protection levels)
1406 CREATE TABLE /*_*/page_restrictions (
1407 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1408 pr_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1409 -- Page to apply restrictions to (Foreign Key to page).
1410 pr_page int NOT NULL,
1411 -- The protection type (edit, move, etc)
1412 pr_type varbinary(60) NOT NULL,
1413 -- The protection level (Sysop, autoconfirmed, etc)
1414 pr_level varbinary(60) NOT NULL,
1415 -- Whether or not to cascade the protection down to pages transcluded.
1416 pr_cascade tinyint NOT NULL,
1417 -- Field for future support of per-user restriction.
1418 pr_user int NULL,
1419 -- Field for time-limited protection.
1420 pr_expiry varbinary(14) NULL
1421 ) /*$wgDBTableOptions*/;
1422
1423 CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
1424 CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
1425 CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
1426 CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);
1427
1428
1429 -- Protected titles - nonexistent pages that have been protected
1430 CREATE TABLE /*_*/protected_titles (
1431 pt_namespace int NOT NULL,
1432 pt_title varchar(255) binary NOT NULL,
1433 pt_user int unsigned NOT NULL,
1434 pt_reason tinyblob,
1435 pt_timestamp binary(14) NOT NULL,
1436 pt_expiry varbinary(14) NOT NULL default '',
1437 pt_create_perm varbinary(60) NOT NULL
1438 ) /*$wgDBTableOptions*/;
1439
1440 CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
1441 CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);
1442
1443
1444 -- Name/value pairs indexed by page_id
1445 CREATE TABLE /*_*/page_props (
1446 pp_page int NOT NULL,
1447 pp_propname varbinary(60) NOT NULL,
1448 pp_value blob NOT NULL,
1449 pp_sortkey float DEFAULT NULL
1450 ) /*$wgDBTableOptions*/;
1451
1452 CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
1453 CREATE UNIQUE INDEX /*i*/pp_propname_page ON /*_*/page_props (pp_propname,pp_page);
1454 CREATE UNIQUE INDEX /*i*/pp_propname_sortkey_page ON /*_*/page_props (pp_propname,pp_sortkey,pp_page);
1455
1456 -- A table to log updates, one text key row per update.
1457 CREATE TABLE /*_*/updatelog (
1458 ul_key varchar(255) NOT NULL PRIMARY KEY,
1459 ul_value blob
1460 ) /*$wgDBTableOptions*/;
1461
1462
1463 -- A table to track tags for revisions, logs and recent changes.
1464 CREATE TABLE /*_*/change_tag (
1465 -- RCID for the change
1466 ct_rc_id int NULL,
1467 -- LOGID for the change
1468 ct_log_id int NULL,
1469 -- REVID for the change
1470 ct_rev_id int NULL,
1471 -- Tag applied
1472 ct_tag varchar(255) NOT NULL,
1473 -- Parameters for the tag, presently unused
1474 ct_params blob NULL
1475 ) /*$wgDBTableOptions*/;
1476
1477 CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
1478 CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
1479 CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
1480 -- Covering index, so we can pull all the info only out of the index.
1481 CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
1482
1483
1484 -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
1485 -- that only works on MySQL 4.1+
1486 CREATE TABLE /*_*/tag_summary (
1487 -- RCID for the change
1488 ts_rc_id int NULL,
1489 -- LOGID for the change
1490 ts_log_id int NULL,
1491 -- REVID for the change
1492 ts_rev_id int NULL,
1493 -- Comma-separated list of tags
1494 ts_tags blob NOT NULL
1495 ) /*$wgDBTableOptions*/;
1496
1497 CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
1498 CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
1499 CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);
1500
1501
1502 CREATE TABLE /*_*/valid_tag (
1503 vt_tag varchar(255) NOT NULL PRIMARY KEY
1504 ) /*$wgDBTableOptions*/;
1505
1506 -- Table for storing localisation data
1507 CREATE TABLE /*_*/l10n_cache (
1508 -- Language code
1509 lc_lang varbinary(32) NOT NULL,
1510 -- Cache key
1511 lc_key varchar(255) NOT NULL,
1512 -- Value
1513 lc_value mediumblob NOT NULL
1514 ) /*$wgDBTableOptions*/;
1515 CREATE INDEX /*i*/lc_lang_key ON /*_*/l10n_cache (lc_lang, lc_key);
1516
1517 -- Table for caching JSON message blobs for the resource loader
1518 CREATE TABLE /*_*/msg_resource (
1519 -- Resource name
1520 mr_resource varbinary(255) NOT NULL,
1521 -- Language code
1522 mr_lang varbinary(32) NOT NULL,
1523 -- JSON blob
1524 mr_blob mediumblob NOT NULL,
1525 -- Timestamp of last update
1526 mr_timestamp binary(14) NOT NULL
1527 ) /*$wgDBTableOptions*/;
1528 CREATE UNIQUE INDEX /*i*/mr_resource_lang ON /*_*/msg_resource (mr_resource, mr_lang);
1529
1530 -- Table for administering which message is contained in which resource
1531 CREATE TABLE /*_*/msg_resource_links (
1532 mrl_resource varbinary(255) NOT NULL,
1533 -- Message key
1534 mrl_message varbinary(255) NOT NULL
1535 ) /*$wgDBTableOptions*/;
1536 CREATE UNIQUE INDEX /*i*/mrl_message_resource ON /*_*/msg_resource_links (mrl_message, mrl_resource);
1537
1538 -- Table caching which local files a module depends on that aren't
1539 -- registered directly, used for fast retrieval of file dependency.
1540 -- Currently only used for tracking images that CSS depends on
1541 CREATE TABLE /*_*/module_deps (
1542 -- Module name
1543 md_module varbinary(255) NOT NULL,
1544 -- Skin name
1545 md_skin varbinary(32) NOT NULL,
1546 -- JSON blob with file dependencies
1547 md_deps mediumblob NOT NULL
1548 ) /*$wgDBTableOptions*/;
1549 CREATE UNIQUE INDEX /*i*/md_module_skin ON /*_*/module_deps (md_module, md_skin);
1550
1551 -- Holds all the sites known to the wiki.
1552 CREATE TABLE /*_*/sites (
1553 -- Numeric id of the site
1554 site_id INT UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
1555
1556 -- Global identifier for the site, ie 'enwiktionary'
1557 site_global_key varbinary(32) NOT NULL,
1558
1559 -- Type of the site, ie 'mediawiki'
1560 site_type varbinary(32) NOT NULL,
1561
1562 -- Group of the site, ie 'wikipedia'
1563 site_group varbinary(32) NOT NULL,
1564
1565 -- Source of the site data, ie 'local', 'wikidata', 'my-magical-repo'
1566 site_source varbinary(32) NOT NULL,
1567
1568 -- Language code of the sites primary language.
1569 site_language varbinary(32) NOT NULL,
1570
1571 -- Protocol of the site, ie 'http://', 'irc://', '//'
1572 -- This field is an index for lookups and is build from type specific data in site_data.
1573 site_protocol varbinary(32) NOT NULL,
1574
1575 -- Domain of the site in reverse order, ie 'org.mediawiki.www.'
1576 -- This field is an index for lookups and is build from type specific data in site_data.
1577 site_domain VARCHAR(255) NOT NULL,
1578
1579 -- Type dependent site data.
1580 site_data BLOB NOT NULL,
1581
1582 -- If site.tld/path/key:pageTitle should forward users to the page on
1583 -- the actual site, where "key" is the local identifier.
1584 site_forward bool NOT NULL,
1585
1586 -- Type dependent site config.
1587 -- For instance if template transclusion should be allowed if it's a MediaWiki.
1588 site_config BLOB NOT NULL
1589 ) /*$wgDBTableOptions*/;
1590
1591 CREATE UNIQUE INDEX /*i*/sites_global_key ON /*_*/sites (site_global_key);
1592 CREATE INDEX /*i*/sites_type ON /*_*/sites (site_type);
1593 CREATE INDEX /*i*/sites_group ON /*_*/sites (site_group);
1594 CREATE INDEX /*i*/sites_source ON /*_*/sites (site_source);
1595 CREATE INDEX /*i*/sites_language ON /*_*/sites (site_language);
1596 CREATE INDEX /*i*/sites_protocol ON /*_*/sites (site_protocol);
1597 CREATE INDEX /*i*/sites_domain ON /*_*/sites (site_domain);
1598 CREATE INDEX /*i*/sites_forward ON /*_*/sites (site_forward);
1599
1600 -- Links local site identifiers to their corresponding site.
1601 CREATE TABLE /*_*/site_identifiers (
1602 -- Key on site.site_id
1603 si_site INT UNSIGNED NOT NULL,
1604
1605 -- local key type, ie 'interwiki' or 'langlink'
1606 si_type varbinary(32) NOT NULL,
1607
1608 -- local key value, ie 'en' or 'wiktionary'
1609 si_key varbinary(32) NOT NULL
1610 ) /*$wgDBTableOptions*/;
1611
1612 CREATE UNIQUE INDEX /*i*/site_ids_type ON /*_*/site_identifiers (si_type, si_key);
1613 CREATE INDEX /*i*/site_ids_site ON /*_*/site_identifiers (si_site);
1614 CREATE INDEX /*i*/site_ids_key ON /*_*/site_identifiers (si_key);
1615
1616 -- vim: sw=2 sts=2 et