[ Index ] |
PHP Cross Reference of MediaWiki-1.24.0 |
[Summary view] [Print] [Text view]
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 -- utf8: 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. 380 -- object: text field contained a serialized PHP object. 381 -- The object either contains multiple versions compressed 382 -- together to achieve a better compression ratio, or it refers 383 -- to another row where the text can be found. 384 old_flags tinyblob NOT NULL 385 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=10240; 386 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit 387 388 389 -- 390 -- Holding area for deleted articles, which may be viewed 391 -- or restored by admins through the Special:Undelete interface. 392 -- The fields generally correspond to the page, revision, and text 393 -- fields, with several caveats. 394 -- 395 CREATE TABLE /*_*/archive ( 396 -- Primary key 397 ar_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT, 398 ar_namespace int NOT NULL default 0, 399 ar_title varchar(255) binary NOT NULL default '', 400 401 -- Newly deleted pages will not store text in this table, 402 -- but will reference the separately existing text rows. 403 -- This field is retained for backwards compatibility, 404 -- so old archived pages will remain accessible after 405 -- upgrading from 1.4 to 1.5. 406 -- Text may be gzipped or otherwise funky. 407 ar_text mediumblob NOT NULL, 408 409 -- Basic revision stuff... 410 ar_comment tinyblob NOT NULL, 411 ar_user int unsigned NOT NULL default 0, 412 ar_user_text varchar(255) binary NOT NULL, 413 ar_timestamp binary(14) NOT NULL default '', 414 ar_minor_edit tinyint NOT NULL default 0, 415 416 -- See ar_text note. 417 ar_flags tinyblob NOT NULL, 418 419 -- When revisions are deleted, their unique rev_id is stored 420 -- here so it can be retained after undeletion. This is necessary 421 -- to retain permalinks to given revisions after accidental delete 422 -- cycles or messy operations like history merges. 423 -- 424 -- Old entries from 1.4 will be NULL here, and a new rev_id will 425 -- be created on undeletion for those revisions. 426 ar_rev_id int unsigned, 427 428 -- For newly deleted revisions, this is the text.old_id key to the 429 -- actual stored text. To avoid breaking the block-compression scheme 430 -- and otherwise making storage changes harder, the actual text is 431 -- *not* deleted from the text table, merely hidden by removal of the 432 -- page and revision entries. 433 -- 434 -- Old entries deleted under 1.2-1.4 will have NULL here, and their 435 -- ar_text and ar_flags fields will be used to create a new text 436 -- row upon undeletion. 437 ar_text_id int unsigned, 438 439 -- rev_deleted for archives 440 ar_deleted tinyint unsigned NOT NULL default 0, 441 442 -- Length of this revision in bytes 443 ar_len int unsigned, 444 445 -- Reference to page_id. Useful for sysadmin fixing of large pages 446 -- merged together in the archives, or for cleanly restoring a page 447 -- at its original ID number if possible. 448 -- 449 -- Will be NULL for pages deleted prior to 1.11. 450 ar_page_id int unsigned, 451 452 -- Original previous revision 453 ar_parent_id int unsigned default NULL, 454 455 -- SHA-1 text content hash in base-36 456 ar_sha1 varbinary(32) NOT NULL default '', 457 458 -- content model, see CONTENT_MODEL_XXX constants 459 ar_content_model varbinary(32) DEFAULT NULL, 460 461 -- content format, see CONTENT_FORMAT_XXX constants 462 ar_content_format varbinary(64) DEFAULT NULL 463 ) /*$wgDBTableOptions*/; 464 465 CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp); 466 CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp); 467 CREATE INDEX /*i*/ar_revid ON /*_*/archive (ar_rev_id); 468 469 470 -- 471 -- Track page-to-page hyperlinks within the wiki. 472 -- 473 CREATE TABLE /*_*/pagelinks ( 474 -- Key to the page_id of the page containing the link. 475 pl_from int unsigned NOT NULL default 0, 476 -- Namespace for this page 477 pl_from_namespace int NOT NULL default 0, 478 479 -- Key to page_namespace/page_title of the target page. 480 -- The target page may or may not exist, and due to renames 481 -- and deletions may refer to different page records as time 482 -- goes by. 483 pl_namespace int NOT NULL default 0, 484 pl_title varchar(255) binary NOT NULL default '' 485 ) /*$wgDBTableOptions*/; 486 487 CREATE UNIQUE INDEX /*i*/pl_from ON /*_*/pagelinks (pl_from,pl_namespace,pl_title); 488 CREATE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from); 489 CREATE INDEX /*i*/pl_backlinks_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from_namespace,pl_from); 490 491 492 -- 493 -- Track template inclusions. 494 -- 495 CREATE TABLE /*_*/templatelinks ( 496 -- Key to the page_id of the page containing the link. 497 tl_from int unsigned NOT NULL default 0, 498 -- Namespace for this page 499 tl_from_namespace int NOT NULL default 0, 500 501 -- Key to page_namespace/page_title of the target page. 502 -- The target page may or may not exist, and due to renames 503 -- and deletions may refer to different page records as time 504 -- goes by. 505 tl_namespace int NOT NULL default 0, 506 tl_title varchar(255) binary NOT NULL default '' 507 ) /*$wgDBTableOptions*/; 508 509 CREATE UNIQUE INDEX /*i*/tl_from ON /*_*/templatelinks (tl_from,tl_namespace,tl_title); 510 CREATE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from); 511 CREATE INDEX /*i*/tl_backlinks_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from_namespace,tl_from); 512 513 514 -- 515 -- Track links to images *used inline* 516 -- We don't distinguish live from broken links here, so 517 -- they do not need to be changed on upload/removal. 518 -- 519 CREATE TABLE /*_*/imagelinks ( 520 -- Key to page_id of the page containing the image / media link. 521 il_from int unsigned NOT NULL default 0, 522 -- Namespace for this page 523 il_from_namespace int NOT NULL default 0, 524 525 -- Filename of target image. 526 -- This is also the page_title of the file's description page; 527 -- all such pages are in namespace 6 (NS_FILE). 528 il_to varchar(255) binary NOT NULL default '' 529 ) /*$wgDBTableOptions*/; 530 531 CREATE UNIQUE INDEX /*i*/il_from ON /*_*/imagelinks (il_from,il_to); 532 CREATE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from); 533 CREATE INDEX /*i*/il_backlinks_namespace ON /*_*/imagelinks (il_to,il_from_namespace,il_from); 534 535 536 -- 537 -- Track category inclusions *used inline* 538 -- This tracks a single level of category membership 539 -- 540 CREATE TABLE /*_*/categorylinks ( 541 -- Key to page_id of the page defined as a category member. 542 cl_from int unsigned NOT NULL default 0, 543 544 -- Name of the category. 545 -- This is also the page_title of the category's description page; 546 -- all such pages are in namespace 14 (NS_CATEGORY). 547 cl_to varchar(255) binary NOT NULL default '', 548 549 -- A binary string obtained by applying a sortkey generation algorithm 550 -- (Collation::getSortKey()) to page_title, or cl_sortkey_prefix . "\n" 551 -- . page_title if cl_sortkey_prefix is nonempty. 552 cl_sortkey varbinary(230) NOT NULL default '', 553 554 -- A prefix for the raw sortkey manually specified by the user, either via 555 -- [[Category:Foo|prefix]] or {{defaultsort:prefix}}. If nonempty, it's 556 -- concatenated with a line break followed by the page title before the sortkey 557 -- conversion algorithm is run. We store this so that we can update 558 -- collations without reparsing all pages. 559 -- Note: If you change the length of this field, you also need to change 560 -- code in LinksUpdate.php. See bug 25254. 561 cl_sortkey_prefix varchar(255) binary NOT NULL default '', 562 563 -- This isn't really used at present. Provided for an optional 564 -- sorting method by approximate addition time. 565 cl_timestamp timestamp NOT NULL, 566 567 -- Stores $wgCategoryCollation at the time cl_sortkey was generated. This 568 -- can be used to install new collation versions, tracking which rows are not 569 -- yet updated. '' means no collation, this is a legacy row that needs to be 570 -- updated by updateCollation.php. In the future, it might be possible to 571 -- specify different collations per category. 572 cl_collation varbinary(32) NOT NULL default '', 573 574 -- Stores whether cl_from is a category, file, or other page, so we can 575 -- paginate the three categories separately. This never has to be updated 576 -- after the page is created, since none of these page types can be moved to 577 -- any other. 578 cl_type ENUM('page', 'subcat', 'file') NOT NULL default 'page' 579 ) /*$wgDBTableOptions*/; 580 581 CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to); 582 583 -- We always sort within a given category, and within a given type. FIXME: 584 -- Formerly this index didn't cover cl_type (since that didn't exist), so old 585 -- callers won't be using an index: fix this? 586 CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_type,cl_sortkey,cl_from); 587 588 -- Used by the API (and some extensions) 589 CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp); 590 591 -- FIXME: Not used, delete this 592 CREATE INDEX /*i*/cl_collation ON /*_*/categorylinks (cl_collation); 593 594 -- 595 -- Track all existing categories. Something is a category if 1) it has an en- 596 -- try somewhere in categorylinks, or 2) it once did. Categories might not 597 -- have corresponding pages, so they need to be tracked separately. 598 -- 599 CREATE TABLE /*_*/category ( 600 -- Primary key 601 cat_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT, 602 603 -- Name of the category, in the same form as page_title (with underscores). 604 -- If there is a category page corresponding to this category, by definition, 605 -- it has this name (in the Category namespace). 606 cat_title varchar(255) binary NOT NULL, 607 608 -- The numbers of member pages (including categories and media), subcatego- 609 -- ries, and Image: namespace members, respectively. These are signed to 610 -- make underflow more obvious. We make the first number include the second 611 -- two for better sorting: subtracting for display is easy, adding for order- 612 -- ing is not. 613 cat_pages int signed NOT NULL default 0, 614 cat_subcats int signed NOT NULL default 0, 615 cat_files int signed NOT NULL default 0 616 ) /*$wgDBTableOptions*/; 617 618 CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title); 619 620 -- For Special:Mostlinkedcategories 621 CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages); 622 623 624 -- 625 -- Track links to external URLs 626 -- 627 CREATE TABLE /*_*/externallinks ( 628 -- Primary key 629 el_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT, 630 631 -- page_id of the referring page 632 el_from int unsigned NOT NULL default 0, 633 634 -- The URL 635 el_to blob NOT NULL, 636 637 -- In the case of HTTP URLs, this is the URL with any username or password 638 -- removed, and with the labels in the hostname reversed and converted to 639 -- lower case. An extra dot is added to allow for matching of either 640 -- example.com or *.example.com in a single scan. 641 -- Example: 642 -- http://user:[email protected]/page.html 643 -- becomes 644 -- http://com.example.sub./page.html 645 -- which allows for fast searching for all pages under example.com with the 646 -- clause: 647 -- WHERE el_index LIKE 'http://com.example.%' 648 el_index blob NOT NULL 649 ) /*$wgDBTableOptions*/; 650 651 CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from, el_to(40)); 652 CREATE INDEX /*i*/el_to ON /*_*/externallinks (el_to(60), el_from); 653 CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index(60)); 654 655 -- 656 -- Track interlanguage links 657 -- 658 CREATE TABLE /*_*/langlinks ( 659 -- page_id of the referring page 660 ll_from int unsigned NOT NULL default 0, 661 662 -- Language code of the target 663 ll_lang varbinary(20) NOT NULL default '', 664 665 -- Title of the target, including namespace 666 ll_title varchar(255) binary NOT NULL default '' 667 ) /*$wgDBTableOptions*/; 668 669 CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang); 670 CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title); 671 672 673 -- 674 -- Track inline interwiki links 675 -- 676 CREATE TABLE /*_*/iwlinks ( 677 -- page_id of the referring page 678 iwl_from int unsigned NOT NULL default 0, 679 680 -- Interwiki prefix code of the target 681 iwl_prefix varbinary(20) NOT NULL default '', 682 683 -- Title of the target, including namespace 684 iwl_title varchar(255) binary NOT NULL default '' 685 ) /*$wgDBTableOptions*/; 686 687 CREATE UNIQUE INDEX /*i*/iwl_from ON /*_*/iwlinks (iwl_from, iwl_prefix, iwl_title); 688 CREATE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from); 689 CREATE INDEX /*i*/iwl_prefix_from_title ON /*_*/iwlinks (iwl_prefix, iwl_from, iwl_title); 690 691 692 -- 693 -- Contains a single row with some aggregate info 694 -- on the state of the site. 695 -- 696 CREATE TABLE /*_*/site_stats ( 697 -- The single row should contain 1 here. 698 ss_row_id int unsigned NOT NULL, 699 700 -- Total number of page views, if hit counters are enabled. 701 ss_total_views bigint unsigned default 0, 702 703 -- Total number of edits performed. 704 ss_total_edits bigint unsigned default 0, 705 706 -- An approximate count of pages matching the following criteria: 707 -- * in namespace 0 708 -- * not a redirect 709 -- * contains the text '[[' 710 -- See Article::isCountable() in includes/Article.php 711 ss_good_articles bigint unsigned default 0, 712 713 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster 714 ss_total_pages bigint default '-1', 715 716 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user; 717 ss_users bigint default '-1', 718 719 -- Number of users that still edit 720 ss_active_users bigint default '-1', 721 722 -- Number of images, equivalent to SELECT COUNT(*) FROM image 723 ss_images int default 0 724 ) /*$wgDBTableOptions*/; 725 726 -- Pointless index to assuage developer superstitions 727 CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id); 728 729 730 -- 731 -- Stores an ID for every time any article is visited; 732 -- depending on $wgHitcounterUpdateFreq, it is 733 -- periodically cleared and the page_counter column 734 -- in the page table updated for all the articles 735 -- that have been visited.) 736 -- 737 CREATE TABLE /*_*/hitcounter ( 738 hc_id int unsigned NOT NULL 739 ) ENGINE=MEMORY MAX_ROWS=25000; 740 741 742 -- 743 -- The internet is full of jerks, alas. Sometimes it's handy 744 -- to block a vandal or troll account. 745 -- 746 CREATE TABLE /*_*/ipblocks ( 747 -- Primary key, introduced for privacy. 748 ipb_id int NOT NULL PRIMARY KEY AUTO_INCREMENT, 749 750 -- Blocked IP address in dotted-quad form or user name. 751 ipb_address tinyblob NOT NULL, 752 753 -- Blocked user ID or 0 for IP blocks. 754 ipb_user int unsigned NOT NULL default 0, 755 756 -- User ID who made the block. 757 ipb_by int unsigned NOT NULL default 0, 758 759 -- User name of blocker 760 ipb_by_text varchar(255) binary NOT NULL default '', 761 762 -- Text comment made by blocker. 763 ipb_reason tinyblob NOT NULL, 764 765 -- Creation (or refresh) date in standard YMDHMS form. 766 -- IP blocks expire automatically. 767 ipb_timestamp binary(14) NOT NULL default '', 768 769 -- Indicates that the IP address was banned because a banned 770 -- user accessed a page through it. If this is 1, ipb_address 771 -- will be hidden, and the block identified by block ID number. 772 ipb_auto bool NOT NULL default 0, 773 774 -- If set to 1, block applies only to logged-out users 775 ipb_anon_only bool NOT NULL default 0, 776 777 -- Block prevents account creation from matching IP addresses 778 ipb_create_account bool NOT NULL default 1, 779 780 -- Block triggers autoblocks 781 ipb_enable_autoblock bool NOT NULL default '1', 782 783 -- Time at which the block will expire. 784 -- May be "infinity" 785 ipb_expiry varbinary(14) NOT NULL default '', 786 787 -- Start and end of an address range, in hexadecimal 788 -- Size chosen to allow IPv6 789 -- FIXME: these fields were originally blank for single-IP blocks, 790 -- but now they are populated. No migration was ever done. They 791 -- should be fixed to be blank again for such blocks (bug 49504). 792 ipb_range_start tinyblob NOT NULL, 793 ipb_range_end tinyblob NOT NULL, 794 795 -- Flag for entries hidden from users and Sysops 796 ipb_deleted bool NOT NULL default 0, 797 798 -- Block prevents user from accessing Special:Emailuser 799 ipb_block_email bool NOT NULL default 0, 800 801 -- Block allows user to edit their own talk page 802 ipb_allow_usertalk bool NOT NULL default 0, 803 804 -- ID of the block that caused this block to exist 805 -- Autoblocks set this to the original block 806 -- so that the original block being deleted also 807 -- deletes the autoblocks 808 ipb_parent_block_id int default NULL 809 810 ) /*$wgDBTableOptions*/; 811 812 -- Unique index to support "user already blocked" messages 813 -- Any new options which prevent collisions should be included 814 CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only); 815 816 CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user); 817 CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start(8), ipb_range_end(8)); 818 CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp); 819 CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry); 820 CREATE INDEX /*i*/ipb_parent_block_id ON /*_*/ipblocks (ipb_parent_block_id); 821 822 823 -- 824 -- Uploaded images and other files. 825 -- 826 CREATE TABLE /*_*/image ( 827 -- Filename. 828 -- This is also the title of the associated description page, 829 -- which will be in namespace 6 (NS_FILE). 830 img_name varchar(255) binary NOT NULL default '' PRIMARY KEY, 831 832 -- File size in bytes. 833 img_size int unsigned NOT NULL default 0, 834 835 -- For images, size in pixels. 836 img_width int NOT NULL default 0, 837 img_height int NOT NULL default 0, 838 839 -- Extracted Exif metadata stored as a serialized PHP array. 840 img_metadata mediumblob NOT NULL, 841 842 -- For images, bits per pixel if known. 843 img_bits int NOT NULL default 0, 844 845 -- Media type as defined by the MEDIATYPE_xxx constants 846 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL, 847 848 -- major part of a MIME media type as defined by IANA 849 -- see http://www.iana.org/assignments/media-types/ 850 -- for "chemical" cf. http://dx.doi.org/10.1021/ci9803233 by the ACS 851 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown", 852 853 -- minor part of a MIME media type as defined by IANA 854 -- the minor parts are not required to adher to any standard 855 -- but should be consistent throughout the database 856 -- see http://www.iana.org/assignments/media-types/ 857 img_minor_mime varbinary(100) NOT NULL default "unknown", 858 859 -- Description field as entered by the uploader. 860 -- This is displayed in image upload history and logs. 861 img_description tinyblob NOT NULL, 862 863 -- user_id and user_name of uploader. 864 img_user int unsigned NOT NULL default 0, 865 img_user_text varchar(255) binary NOT NULL, 866 867 -- Time of the upload. 868 img_timestamp varbinary(14) NOT NULL default '', 869 870 -- SHA-1 content hash in base-36 871 img_sha1 varbinary(32) NOT NULL default '' 872 ) /*$wgDBTableOptions*/; 873 874 CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp); 875 -- Used by Special:ListFiles for sort-by-size 876 CREATE INDEX /*i*/img_size ON /*_*/image (img_size); 877 -- Used by Special:Newimages and Special:ListFiles 878 CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp); 879 -- Used in API and duplicate search 880 CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1(10)); 881 -- Used to get media of one type 882 CREATE INDEX /*i*/img_media_mime ON /*_*/image (img_media_type,img_major_mime,img_minor_mime); 883 884 885 -- 886 -- Previous revisions of uploaded files. 887 -- Awkwardly, image rows have to be moved into 888 -- this table at re-upload time. 889 -- 890 CREATE TABLE /*_*/oldimage ( 891 -- Base filename: key to image.img_name 892 oi_name varchar(255) binary NOT NULL default '', 893 894 -- Filename of the archived file. 895 -- This is generally a timestamp and '!' prepended to the base name. 896 oi_archive_name varchar(255) binary NOT NULL default '', 897 898 -- Other fields as in image... 899 oi_size int unsigned NOT NULL default 0, 900 oi_width int NOT NULL default 0, 901 oi_height int NOT NULL default 0, 902 oi_bits int NOT NULL default 0, 903 oi_description tinyblob NOT NULL, 904 oi_user int unsigned NOT NULL default 0, 905 oi_user_text varchar(255) binary NOT NULL, 906 oi_timestamp binary(14) NOT NULL default '', 907 908 oi_metadata mediumblob NOT NULL, 909 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL, 910 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown", 911 oi_minor_mime varbinary(100) NOT NULL default "unknown", 912 oi_deleted tinyint unsigned NOT NULL default 0, 913 oi_sha1 varbinary(32) NOT NULL default '' 914 ) /*$wgDBTableOptions*/; 915 916 CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp); 917 CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp); 918 -- oi_archive_name truncated to 14 to avoid key length overflow 919 CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name(14)); 920 CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1(10)); 921 922 923 -- 924 -- Record of deleted file data 925 -- 926 CREATE TABLE /*_*/filearchive ( 927 -- Unique row id 928 fa_id int NOT NULL PRIMARY KEY AUTO_INCREMENT, 929 930 -- Original base filename; key to image.img_name, page.page_title, etc 931 fa_name varchar(255) binary NOT NULL default '', 932 933 -- Filename of archived file, if an old revision 934 fa_archive_name varchar(255) binary default '', 935 936 -- Which storage bin (directory tree or object store) the file data 937 -- is stored in. Should be 'deleted' for files that have been deleted; 938 -- any other bin is not yet in use. 939 fa_storage_group varbinary(16), 940 941 -- SHA-1 of the file contents plus extension, used as a key for storage. 942 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg 943 -- 944 -- If NULL, the file was missing at deletion time or has been purged 945 -- from the archival storage. 946 fa_storage_key varbinary(64) default '', 947 948 -- Deletion information, if this file is deleted. 949 fa_deleted_user int, 950 fa_deleted_timestamp binary(14) default '', 951 fa_deleted_reason text, 952 953 -- Duped fields from image 954 fa_size int unsigned default 0, 955 fa_width int default 0, 956 fa_height int default 0, 957 fa_metadata mediumblob, 958 fa_bits int default 0, 959 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL, 960 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") default "unknown", 961 fa_minor_mime varbinary(100) default "unknown", 962 fa_description tinyblob, 963 fa_user int unsigned default 0, 964 fa_user_text varchar(255) binary, 965 fa_timestamp binary(14) default '', 966 967 -- Visibility of deleted revisions, bitfield 968 fa_deleted tinyint unsigned NOT NULL default 0, 969 970 -- sha1 hash of file content 971 fa_sha1 varbinary(32) NOT NULL default '' 972 ) /*$wgDBTableOptions*/; 973 974 -- pick out by image name 975 CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp); 976 -- pick out dupe files 977 CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key); 978 -- sort by deletion time 979 CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp); 980 -- sort by uploader 981 CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp); 982 -- find file by sha1, 10 bytes will be enough for hashes to be indexed 983 CREATE INDEX /*i*/fa_sha1 ON /*_*/filearchive (fa_sha1(10)); 984 985 986 -- 987 -- Store information about newly uploaded files before they're 988 -- moved into the actual filestore 989 -- 990 CREATE TABLE /*_*/uploadstash ( 991 us_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT, 992 993 -- the user who uploaded the file. 994 us_user int unsigned NOT NULL, 995 996 -- file key. this is how applications actually search for the file. 997 -- this might go away, or become the primary key. 998 us_key varchar(255) NOT NULL, 999 1000 -- the original path 1001 us_orig_path varchar(255) NOT NULL, 1002 1003 -- the temporary path at which the file is actually stored 1004 us_path varchar(255) NOT NULL, 1005 1006 -- which type of upload the file came from (sometimes) 1007 us_source_type varchar(50), 1008 1009 -- the date/time on which the file was added 1010 us_timestamp varbinary(14) NOT NULL, 1011 1012 us_status varchar(50) NOT NULL, 1013 1014 -- chunk counter starts at 0, current offset is stored in us_size 1015 us_chunk_inx int unsigned NULL, 1016 1017 -- Serialized file properties from FSFile::getProps() 1018 us_props blob, 1019 1020 -- file size in bytes 1021 us_size int unsigned NOT NULL, 1022 -- this hash comes from FSFile::getSha1Base36(), and is 31 characters 1023 us_sha1 varchar(31) NOT NULL, 1024 us_mime varchar(255), 1025 -- Media type as defined by the MEDIATYPE_xxx constants, should duplicate definition in the image table 1026 us_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL, 1027 -- image-specific properties 1028 us_image_width int unsigned, 1029 us_image_height int unsigned, 1030 us_image_bits smallint unsigned 1031 1032 ) /*$wgDBTableOptions*/; 1033 1034 -- sometimes there's a delete for all of a user's stuff. 1035 CREATE INDEX /*i*/us_user ON /*_*/uploadstash (us_user); 1036 -- pick out files by key, enforce key uniqueness 1037 CREATE UNIQUE INDEX /*i*/us_key ON /*_*/uploadstash (us_key); 1038 -- the abandoned upload cleanup script needs this 1039 CREATE INDEX /*i*/us_timestamp ON /*_*/uploadstash (us_timestamp); 1040 1041 1042 -- 1043 -- Primarily a summary table for Special:Recentchanges, 1044 -- this table contains some additional info on edits from 1045 -- the last few days, see Article::editUpdates() 1046 -- 1047 CREATE TABLE /*_*/recentchanges ( 1048 rc_id int NOT NULL PRIMARY KEY AUTO_INCREMENT, 1049 rc_timestamp varbinary(14) NOT NULL default '', 1050 1051 -- As in revision 1052 rc_user int unsigned NOT NULL default 0, 1053 rc_user_text varchar(255) binary NOT NULL, 1054 1055 -- When pages are renamed, their RC entries do _not_ change. 1056 rc_namespace int NOT NULL default 0, 1057 rc_title varchar(255) binary NOT NULL default '', 1058 1059 -- as in revision... 1060 rc_comment varchar(255) binary NOT NULL default '', 1061 rc_minor tinyint unsigned NOT NULL default 0, 1062 1063 -- Edits by user accounts with the 'bot' rights key are 1064 -- marked with a 1 here, and will be hidden from the 1065 -- default view. 1066 rc_bot tinyint unsigned NOT NULL default 0, 1067 1068 -- Set if this change corresponds to a page creation 1069 rc_new tinyint unsigned NOT NULL default 0, 1070 1071 -- Key to page_id (was cur_id prior to 1.5). 1072 -- This will keep links working after moves while 1073 -- retaining the at-the-time name in the changes list. 1074 rc_cur_id int unsigned NOT NULL default 0, 1075 1076 -- rev_id of the given revision 1077 rc_this_oldid int unsigned NOT NULL default 0, 1078 1079 -- rev_id of the prior revision, for generating diff links. 1080 rc_last_oldid int unsigned NOT NULL default 0, 1081 1082 -- The type of change entry (RC_EDIT,RC_NEW,RC_LOG,RC_EXTERNAL) 1083 rc_type tinyint unsigned NOT NULL default 0, 1084 1085 -- The source of the change entry (replaces rc_type) 1086 -- default of '' is temporary, needed for initial migration 1087 rc_source varchar(16) binary not null default '', 1088 1089 -- If the Recent Changes Patrol option is enabled, 1090 -- users may mark edits as having been reviewed to 1091 -- remove a warning flag on the RC list. 1092 -- A value of 1 indicates the page has been reviewed. 1093 rc_patrolled tinyint unsigned NOT NULL default 0, 1094 1095 -- Recorded IP address the edit was made from, if the 1096 -- $wgPutIPinRC option is enabled. 1097 rc_ip varbinary(40) NOT NULL default '', 1098 1099 -- Text length in characters before 1100 -- and after the edit 1101 rc_old_len int, 1102 rc_new_len int, 1103 1104 -- Visibility of recent changes items, bitfield 1105 rc_deleted tinyint unsigned NOT NULL default 0, 1106 1107 -- Value corresponding to log_id, specific log entries 1108 rc_logid int unsigned NOT NULL default 0, 1109 -- Store log type info here, or null 1110 rc_log_type varbinary(255) NULL default NULL, 1111 -- Store log action or null 1112 rc_log_action varbinary(255) NULL default NULL, 1113 -- Log params 1114 rc_params blob NULL 1115 ) /*$wgDBTableOptions*/; 1116 1117 CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp); 1118 CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title); 1119 CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id); 1120 CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp); 1121 CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip); 1122 CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text); 1123 CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp); 1124 1125 1126 CREATE TABLE /*_*/watchlist ( 1127 -- Key to user.user_id 1128 wl_user int unsigned NOT NULL, 1129 1130 -- Key to page_namespace/page_title 1131 -- Note that users may watch pages which do not exist yet, 1132 -- or existed in the past but have been deleted. 1133 wl_namespace int NOT NULL default 0, 1134 wl_title varchar(255) binary NOT NULL default '', 1135 1136 -- Timestamp used to send notification e-mails and show "updated since last visit" markers on 1137 -- history and recent changes / watchlist. Set to NULL when the user visits the latest revision 1138 -- of the page, which means that they should be sent an e-mail on the next change. 1139 wl_notificationtimestamp varbinary(14) 1140 1141 ) /*$wgDBTableOptions*/; 1142 1143 CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title); 1144 CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title); 1145 CREATE INDEX /*i*/wl_user_notificationtimestamp ON /*_*/watchlist (wl_user, wl_notificationtimestamp); 1146 1147 1148 -- 1149 -- When using the default MySQL search backend, page titles 1150 -- and text are munged to strip markup, do Unicode case folding, 1151 -- and prepare the result for MySQL's fulltext index. 1152 -- 1153 -- This table must be MyISAM; InnoDB does not support the needed 1154 -- fulltext index. 1155 -- 1156 CREATE TABLE /*_*/searchindex ( 1157 -- Key to page_id 1158 si_page int unsigned NOT NULL, 1159 1160 -- Munged version of title 1161 si_title varchar(255) NOT NULL default '', 1162 1163 -- Munged version of body text 1164 si_text mediumtext NOT NULL 1165 ) ENGINE=MyISAM DEFAULT CHARSET=utf8; 1166 1167 CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page); 1168 CREATE FULLTEXT INDEX /*i*/si_title ON /*_*/searchindex (si_title); 1169 CREATE FULLTEXT INDEX /*i*/si_text ON /*_*/searchindex (si_text); 1170 1171 1172 -- 1173 -- Recognized interwiki link prefixes 1174 -- 1175 CREATE TABLE /*_*/interwiki ( 1176 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de") 1177 iw_prefix varchar(32) NOT NULL, 1178 1179 -- The URL of the wiki, with "$1" as a placeholder for an article name. 1180 -- Any spaces in the name will be transformed to underscores before 1181 -- insertion. 1182 iw_url blob NOT NULL, 1183 1184 -- The URL of the file api.php 1185 iw_api blob NOT NULL, 1186 1187 -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' )) 1188 iw_wikiid varchar(64) NOT NULL, 1189 1190 -- A boolean value indicating whether the wiki is in this project 1191 -- (used, for example, to detect redirect loops) 1192 iw_local bool NOT NULL, 1193 1194 -- Boolean value indicating whether interwiki transclusions are allowed. 1195 iw_trans tinyint NOT NULL default 0 1196 ) /*$wgDBTableOptions*/; 1197 1198 CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix); 1199 1200 1201 -- 1202 -- Used for caching expensive grouped queries 1203 -- 1204 CREATE TABLE /*_*/querycache ( 1205 -- A key name, generally the base name of of the special page. 1206 qc_type varbinary(32) NOT NULL, 1207 1208 -- Some sort of stored value. Sizes, counts... 1209 qc_value int unsigned NOT NULL default 0, 1210 1211 -- Target namespace+title 1212 qc_namespace int NOT NULL default 0, 1213 qc_title varchar(255) binary NOT NULL default '' 1214 ) /*$wgDBTableOptions*/; 1215 1216 CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value); 1217 1218 1219 -- 1220 -- For a few generic cache operations if not using Memcached 1221 -- 1222 CREATE TABLE /*_*/objectcache ( 1223 keyname varbinary(255) NOT NULL default '' PRIMARY KEY, 1224 value mediumblob, 1225 exptime datetime 1226 ) /*$wgDBTableOptions*/; 1227 CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime); 1228 1229 1230 -- 1231 -- Cache of interwiki transclusion 1232 -- 1233 CREATE TABLE /*_*/transcache ( 1234 tc_url varbinary(255) NOT NULL, 1235 tc_contents text, 1236 tc_time binary(14) NOT NULL 1237 ) /*$wgDBTableOptions*/; 1238 1239 CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url); 1240 1241 1242 CREATE TABLE /*_*/logging ( 1243 -- Log ID, for referring to this specific log entry, probably for deletion and such. 1244 log_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT, 1245 1246 -- Symbolic keys for the general log type and the action type 1247 -- within the log. The output format will be controlled by the 1248 -- action field, but only the type controls categorization. 1249 log_type varbinary(32) NOT NULL default '', 1250 log_action varbinary(32) NOT NULL default '', 1251 1252 -- Timestamp. Duh. 1253 log_timestamp binary(14) NOT NULL default '19700101000000', 1254 1255 -- The user who performed this action; key to user_id 1256 log_user int unsigned NOT NULL default 0, 1257 1258 -- Name of the user who performed this action 1259 log_user_text varchar(255) binary NOT NULL default '', 1260 1261 -- Key to the page affected. Where a user is the target, 1262 -- this will point to the user page. 1263 log_namespace int NOT NULL default 0, 1264 log_title varchar(255) binary NOT NULL default '', 1265 log_page int unsigned NULL, 1266 1267 -- Freeform text. Interpreted as edit history comments. 1268 log_comment varchar(255) NOT NULL default '', 1269 1270 -- miscellaneous parameters: 1271 -- LF separated list (old system) or serialized PHP array (new system) 1272 log_params blob NOT NULL, 1273 1274 -- rev_deleted for logs 1275 log_deleted tinyint unsigned NOT NULL default 0 1276 ) /*$wgDBTableOptions*/; 1277 1278 CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp); 1279 CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp); 1280 CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp); 1281 CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp); 1282 CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp); 1283 CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp); 1284 CREATE INDEX /*i*/type_action ON /*_*/logging (log_type, log_action, log_timestamp); 1285 CREATE INDEX /*i*/log_user_text_type_time ON /*_*/logging (log_user_text, log_type, log_timestamp); 1286 CREATE INDEX /*i*/log_user_text_time ON /*_*/logging (log_user_text, log_timestamp); 1287 1288 1289 CREATE TABLE /*_*/log_search ( 1290 -- The type of ID (rev ID, log ID, rev timestamp, username) 1291 ls_field varbinary(32) NOT NULL, 1292 -- The value of the ID 1293 ls_value varchar(255) NOT NULL, 1294 -- Key to log_id 1295 ls_log_id int unsigned NOT NULL default 0 1296 ) /*$wgDBTableOptions*/; 1297 CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id); 1298 CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id); 1299 1300 1301 -- Jobs performed by parallel apache threads or a command-line daemon 1302 CREATE TABLE /*_*/job ( 1303 job_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT, 1304 1305 -- Command name 1306 -- Limited to 60 to prevent key length overflow 1307 job_cmd varbinary(60) NOT NULL default '', 1308 1309 -- Namespace and title to act on 1310 -- Should be 0 and '' if the command does not operate on a title 1311 job_namespace int NOT NULL, 1312 job_title varchar(255) binary NOT NULL, 1313 1314 -- Timestamp of when the job was inserted 1315 -- NULL for jobs added before addition of the timestamp 1316 job_timestamp varbinary(14) NULL default NULL, 1317 1318 -- Any other parameters to the command 1319 -- Stored as a PHP serialized array, or an empty string if there are no parameters 1320 job_params blob NOT NULL, 1321 1322 -- Random, non-unique, number used for job acquisition (for lock concurrency) 1323 job_random integer unsigned NOT NULL default 0, 1324 1325 -- The number of times this job has been locked 1326 job_attempts integer unsigned NOT NULL default 0, 1327 1328 -- Field that conveys process locks on rows via process UUIDs 1329 job_token varbinary(32) NOT NULL default '', 1330 1331 -- Timestamp when the job was locked 1332 job_token_timestamp varbinary(14) NULL default NULL, 1333 1334 -- Base 36 SHA1 of the job parameters relevant to detecting duplicates 1335 job_sha1 varbinary(32) NOT NULL default '' 1336 ) /*$wgDBTableOptions*/; 1337 1338 CREATE INDEX /*i*/job_sha1 ON /*_*/job (job_sha1); 1339 CREATE INDEX /*i*/job_cmd_token ON /*_*/job (job_cmd,job_token,job_random); 1340 CREATE INDEX /*i*/job_cmd_token_id ON /*_*/job (job_cmd,job_token,job_id); 1341 CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title, job_params(128)); 1342 CREATE INDEX /*i*/job_timestamp ON /*_*/job (job_timestamp); 1343 1344 1345 -- Details of updates to cached special pages 1346 CREATE TABLE /*_*/querycache_info ( 1347 -- Special page name 1348 -- Corresponds to a qc_type value 1349 qci_type varbinary(32) NOT NULL default '', 1350 1351 -- Timestamp of last update 1352 qci_timestamp binary(14) NOT NULL default '19700101000000' 1353 ) /*$wgDBTableOptions*/; 1354 1355 CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type); 1356 1357 1358 -- For each redirect, this table contains exactly one row defining its target 1359 CREATE TABLE /*_*/redirect ( 1360 -- Key to the page_id of the redirect page 1361 rd_from int unsigned NOT NULL default 0 PRIMARY KEY, 1362 1363 -- Key to page_namespace/page_title of the target page. 1364 -- The target page may or may not exist, and due to renames 1365 -- and deletions may refer to different page records as time 1366 -- goes by. 1367 rd_namespace int NOT NULL default 0, 1368 rd_title varchar(255) binary NOT NULL default '', 1369 rd_interwiki varchar(32) default NULL, 1370 rd_fragment varchar(255) binary default NULL 1371 ) /*$wgDBTableOptions*/; 1372 1373 CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from); 1374 1375 1376 -- Used for caching expensive grouped queries that need two links (for example double-redirects) 1377 CREATE TABLE /*_*/querycachetwo ( 1378 -- A key name, generally the base name of of the special page. 1379 qcc_type varbinary(32) NOT NULL, 1380 1381 -- Some sort of stored value. Sizes, counts... 1382 qcc_value int unsigned NOT NULL default 0, 1383 1384 -- Target namespace+title 1385 qcc_namespace int NOT NULL default 0, 1386 qcc_title varchar(255) binary NOT NULL default '', 1387 1388 -- Target namespace+title2 1389 qcc_namespacetwo int NOT NULL default 0, 1390 qcc_titletwo varchar(255) binary NOT NULL default '' 1391 ) /*$wgDBTableOptions*/; 1392 1393 CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value); 1394 CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title); 1395 CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo); 1396 1397 1398 -- Used for storing page restrictions (i.e. protection levels) 1399 CREATE TABLE /*_*/page_restrictions ( 1400 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages) 1401 pr_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT, 1402 -- Page to apply restrictions to (Foreign Key to page). 1403 pr_page int NOT NULL, 1404 -- The protection type (edit, move, etc) 1405 pr_type varbinary(60) NOT NULL, 1406 -- The protection level (Sysop, autoconfirmed, etc) 1407 pr_level varbinary(60) NOT NULL, 1408 -- Whether or not to cascade the protection down to pages transcluded. 1409 pr_cascade tinyint NOT NULL, 1410 -- Field for future support of per-user restriction. 1411 pr_user int NULL, 1412 -- Field for time-limited protection. 1413 pr_expiry varbinary(14) NULL 1414 ) /*$wgDBTableOptions*/; 1415 1416 CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type); 1417 CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level); 1418 CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level); 1419 CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade); 1420 1421 1422 -- Protected titles - nonexistent pages that have been protected 1423 CREATE TABLE /*_*/protected_titles ( 1424 pt_namespace int NOT NULL, 1425 pt_title varchar(255) binary NOT NULL, 1426 pt_user int unsigned NOT NULL, 1427 pt_reason tinyblob, 1428 pt_timestamp binary(14) NOT NULL, 1429 pt_expiry varbinary(14) NOT NULL default '', 1430 pt_create_perm varbinary(60) NOT NULL 1431 ) /*$wgDBTableOptions*/; 1432 1433 CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title); 1434 CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp); 1435 1436 1437 -- Name/value pairs indexed by page_id 1438 CREATE TABLE /*_*/page_props ( 1439 pp_page int NOT NULL, 1440 pp_propname varbinary(60) NOT NULL, 1441 pp_value blob NOT NULL, 1442 pp_sortkey float DEFAULT NULL 1443 ) /*$wgDBTableOptions*/; 1444 1445 CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname); 1446 CREATE UNIQUE INDEX /*i*/pp_propname_page ON /*_*/page_props (pp_propname,pp_page); 1447 CREATE UNIQUE INDEX /*i*/pp_propname_sortkey_page ON /*_*/page_props (pp_propname,pp_sortkey,pp_page); 1448 1449 -- A table to log updates, one text key row per update. 1450 CREATE TABLE /*_*/updatelog ( 1451 ul_key varchar(255) NOT NULL PRIMARY KEY, 1452 ul_value blob 1453 ) /*$wgDBTableOptions*/; 1454 1455 1456 -- A table to track tags for revisions, logs and recent changes. 1457 CREATE TABLE /*_*/change_tag ( 1458 -- RCID for the change 1459 ct_rc_id int NULL, 1460 -- LOGID for the change 1461 ct_log_id int NULL, 1462 -- REVID for the change 1463 ct_rev_id int NULL, 1464 -- Tag applied 1465 ct_tag varchar(255) NOT NULL, 1466 -- Parameters for the tag, presently unused 1467 ct_params blob NULL 1468 ) /*$wgDBTableOptions*/; 1469 1470 CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag); 1471 CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag); 1472 CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag); 1473 -- Covering index, so we can pull all the info only out of the index. 1474 CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id); 1475 1476 1477 -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT 1478 -- that only works on MySQL 4.1+ 1479 CREATE TABLE /*_*/tag_summary ( 1480 -- RCID for the change 1481 ts_rc_id int NULL, 1482 -- LOGID for the change 1483 ts_log_id int NULL, 1484 -- REVID for the change 1485 ts_rev_id int NULL, 1486 -- Comma-separated list of tags 1487 ts_tags blob NOT NULL 1488 ) /*$wgDBTableOptions*/; 1489 1490 CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id); 1491 CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id); 1492 CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id); 1493 1494 1495 CREATE TABLE /*_*/valid_tag ( 1496 vt_tag varchar(255) NOT NULL PRIMARY KEY 1497 ) /*$wgDBTableOptions*/; 1498 1499 -- Table for storing localisation data 1500 CREATE TABLE /*_*/l10n_cache ( 1501 -- Language code 1502 lc_lang varbinary(32) NOT NULL, 1503 -- Cache key 1504 lc_key varchar(255) NOT NULL, 1505 -- Value 1506 lc_value mediumblob NOT NULL 1507 ) /*$wgDBTableOptions*/; 1508 CREATE INDEX /*i*/lc_lang_key ON /*_*/l10n_cache (lc_lang, lc_key); 1509 1510 -- Table for caching JSON message blobs for the resource loader 1511 CREATE TABLE /*_*/msg_resource ( 1512 -- Resource name 1513 mr_resource varbinary(255) NOT NULL, 1514 -- Language code 1515 mr_lang varbinary(32) NOT NULL, 1516 -- JSON blob 1517 mr_blob mediumblob NOT NULL, 1518 -- Timestamp of last update 1519 mr_timestamp binary(14) NOT NULL 1520 ) /*$wgDBTableOptions*/; 1521 CREATE UNIQUE INDEX /*i*/mr_resource_lang ON /*_*/msg_resource (mr_resource, mr_lang); 1522 1523 -- Table for administering which message is contained in which resource 1524 CREATE TABLE /*_*/msg_resource_links ( 1525 mrl_resource varbinary(255) NOT NULL, 1526 -- Message key 1527 mrl_message varbinary(255) NOT NULL 1528 ) /*$wgDBTableOptions*/; 1529 CREATE UNIQUE INDEX /*i*/mrl_message_resource ON /*_*/msg_resource_links (mrl_message, mrl_resource); 1530 1531 -- Table caching which local files a module depends on that aren't 1532 -- registered directly, used for fast retrieval of file dependency. 1533 -- Currently only used for tracking images that CSS depends on 1534 CREATE TABLE /*_*/module_deps ( 1535 -- Module name 1536 md_module varbinary(255) NOT NULL, 1537 -- Skin name 1538 md_skin varbinary(32) NOT NULL, 1539 -- JSON blob with file dependencies 1540 md_deps mediumblob NOT NULL 1541 ) /*$wgDBTableOptions*/; 1542 CREATE UNIQUE INDEX /*i*/md_module_skin ON /*_*/module_deps (md_module, md_skin); 1543 1544 -- Holds all the sites known to the wiki. 1545 CREATE TABLE /*_*/sites ( 1546 -- Numeric id of the site 1547 site_id INT UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT, 1548 1549 -- Global identifier for the site, ie 'enwiktionary' 1550 site_global_key varbinary(32) NOT NULL, 1551 1552 -- Type of the site, ie 'mediawiki' 1553 site_type varbinary(32) NOT NULL, 1554 1555 -- Group of the site, ie 'wikipedia' 1556 site_group varbinary(32) NOT NULL, 1557 1558 -- Source of the site data, ie 'local', 'wikidata', 'my-magical-repo' 1559 site_source varbinary(32) NOT NULL, 1560 1561 -- Language code of the sites primary language. 1562 site_language varbinary(32) NOT NULL, 1563 1564 -- Protocol of the site, ie 'http://', 'irc://', '//' 1565 -- This field is an index for lookups and is build from type specific data in site_data. 1566 site_protocol varbinary(32) NOT NULL, 1567 1568 -- Domain of the site in reverse order, ie 'org.mediawiki.www.' 1569 -- This field is an index for lookups and is build from type specific data in site_data. 1570 site_domain VARCHAR(255) NOT NULL, 1571 1572 -- Type dependent site data. 1573 site_data BLOB NOT NULL, 1574 1575 -- If site.tld/path/key:pageTitle should forward users to the page on 1576 -- the actual site, where "key" is the local identifier. 1577 site_forward bool NOT NULL, 1578 1579 -- Type dependent site config. 1580 -- For instance if template transclusion should be allowed if it's a MediaWiki. 1581 site_config BLOB NOT NULL 1582 ) /*$wgDBTableOptions*/; 1583 1584 CREATE UNIQUE INDEX /*i*/sites_global_key ON /*_*/sites (site_global_key); 1585 CREATE INDEX /*i*/sites_type ON /*_*/sites (site_type); 1586 CREATE INDEX /*i*/sites_group ON /*_*/sites (site_group); 1587 CREATE INDEX /*i*/sites_source ON /*_*/sites (site_source); 1588 CREATE INDEX /*i*/sites_language ON /*_*/sites (site_language); 1589 CREATE INDEX /*i*/sites_protocol ON /*_*/sites (site_protocol); 1590 CREATE INDEX /*i*/sites_domain ON /*_*/sites (site_domain); 1591 CREATE INDEX /*i*/sites_forward ON /*_*/sites (site_forward); 1592 1593 -- Links local site identifiers to their corresponding site. 1594 CREATE TABLE /*_*/site_identifiers ( 1595 -- Key on site.site_id 1596 si_site INT UNSIGNED NOT NULL, 1597 1598 -- local key type, ie 'interwiki' or 'langlink' 1599 si_type varbinary(32) NOT NULL, 1600 1601 -- local key value, ie 'en' or 'wiktionary' 1602 si_key varbinary(32) NOT NULL 1603 ) /*$wgDBTableOptions*/; 1604 1605 CREATE UNIQUE INDEX /*i*/site_ids_type ON /*_*/site_identifiers (si_type, si_key); 1606 CREATE INDEX /*i*/site_ids_site ON /*_*/site_identifiers (si_site); 1607 CREATE INDEX /*i*/site_ids_key ON /*_*/site_identifiers (si_key); 1608 1609 -- vim: sw=2 sts=2 et
title
Description
Body
title
Description
Body
title
Description
Body
title
Body
Generated: Fri Nov 28 14:03:12 2014 | Cross-referenced by PHPXref 0.7.1 |