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