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