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