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