rdbms: update IDatabase::getLag comments
[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 default 0,
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 -- Archive area for deleted pages and their revisions.
576 -- These may be viewed (and restored) by admins through the Special:Undelete interface.
577 --
578 CREATE TABLE /*_*/archive (
579 -- Primary key
580 ar_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
581
582 -- Copied from page_namespace
583 ar_namespace int NOT NULL default 0,
584 -- Copied from page_title
585 ar_title varchar(255) binary NOT NULL default '',
586
587 -- Copied from text.old_text, for pages deleted before MediaWiki 1.5.
588 -- This row may contain the raw revision text, possibly compressed.
589 -- Newer MediaWiki versions use ar_text_id instead.
590 -- This field is retained for backwards compatibility, so that
591 -- old archived pages will remain accessible.
592 -- See migrateArchiveText.php for migrating values to text storage.
593 ar_text mediumblob NOT NULL,
594
595 -- Basic revision stuff...
596 ar_comment varbinary(767) NOT NULL default '', -- Deprecated in favor of ar_comment_id
597 ar_comment_id bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that ar_comment should be used)
598 ar_user int unsigned NOT NULL default 0, -- Deprecated in favor of ar_actor
599 ar_user_text varchar(255) binary NOT NULL DEFAULT '', -- Deprecated in favor of ar_actor
600 ar_actor bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that ar_user/ar_user_text should be used)
601 ar_timestamp binary(14) NOT NULL default '',
602 ar_minor_edit tinyint NOT NULL default 0,
603
604 -- Copied from text.old_flags, for pages deleted before MediaWiki 1.5.
605 -- Otherwise empty string.
606 -- See also note for ar_text.
607 ar_flags tinyblob NOT NULL,
608
609 -- Copied from rev_id.
610 --
611 -- @since 1.5 Entries from 1.4 will be NULL here. When restoring
612 -- archive rows from before 1.5, a new rev_id is created.
613 ar_rev_id int unsigned,
614
615 -- Copied from rev_text_id, references text.old_id.
616 -- To avoid breaking the block-compression scheme and otherwise making
617 -- storage changes harder, the actual text is *not* deleted from the
618 -- text storage. Instead, it is merely hidden from public view, by removal
619 -- of the page and revision entries.
620 --
621 -- @since 1.5 Entries from 1.2-1.4 will have NULL here. When restoring
622 -- archive rows without this, ar_text and ar_flags are used instead.
623 ar_text_id int unsigned,
624
625 -- Copied from rev_deleted. Although this may be raised during deletion.
626 -- Users with the "suppressrevision" right may "archive" and "suppress"
627 -- content in a single action.
628 -- @since 1.10
629 ar_deleted tinyint unsigned NOT NULL default 0,
630
631 -- Copied from rev_len, length of this revision in bytes.
632 -- @since 1.10
633 ar_len int unsigned,
634
635 -- Copied from page_id. Restoration will attempt to use this as page ID if
636 -- no current page with the same name exists. Otherwise, the revisions will
637 -- be restored under the current page. Can be used for manual undeletion by
638 -- developers if multiple pages by the same name were archived.
639 --
640 -- @since 1.11 Older entries will have NULL.
641 ar_page_id int unsigned,
642
643 -- Copied from rev_parent_id.
644 -- @since 1.13
645 ar_parent_id int unsigned default NULL,
646
647 -- Copied from rev_sha1, SHA-1 text content hash in base-36
648 -- @since 1.19
649 ar_sha1 varbinary(32) NOT NULL default '',
650
651 -- Copied from rev_content_model, see CONTENT_MODEL_XXX constants
652 -- @since 1.21
653 ar_content_model varbinary(32) DEFAULT NULL,
654
655 -- Copied from rev_content_format, see CONTENT_FORMAT_XXX constants
656 -- @since 1.21
657 ar_content_format varbinary(64) DEFAULT NULL
658 ) /*$wgDBTableOptions*/;
659
660 -- Index for Special:Undelete to page through deleted revisions
661 CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp);
662
663 -- Index for Special:DeletedContributions
664 CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp);
665 CREATE INDEX /*i*/ar_actor_timestamp ON /*_*/archive (ar_actor,ar_timestamp);
666
667 -- Index for linking archive rows with tables that normally link with revision
668 -- rows, such as change_tag.
669 CREATE INDEX /*i*/ar_revid ON /*_*/archive (ar_rev_id);
670
671 --
672 -- Slots represent an n:m relation between revisions and content objects.
673 -- A content object can have a specific "role" in one or more revisions.
674 -- Each revision can have multiple content objects, each having a different role.
675 --
676 CREATE TABLE /*_*/slots (
677
678 -- reference to rev_id
679 slot_revision_id bigint unsigned NOT NULL,
680
681 -- reference to role_id
682 slot_role_id smallint unsigned NOT NULL,
683
684 -- reference to content_id
685 slot_content_id bigint unsigned NOT NULL,
686
687 -- The revision ID of the revision that originated the slot's content.
688 -- To find revisions that changed slots, look for slot_origin = slot_revision_id.
689 slot_origin bigint unsigned NOT NULL,
690
691 PRIMARY KEY ( slot_revision_id, slot_role_id )
692 ) /*$wgDBTableOptions*/;
693
694 -- Index for finding revisions that modified a specific slot
695 CREATE INDEX /*i*/slot_revision_origin_role ON /*_*/slots (slot_revision_id, slot_origin, slot_role_id);
696
697 --
698 -- The content table represents content objects. It's primary purpose is to provide the necessary
699 -- meta-data for loading and interpreting a serialized data blob to create a content object.
700 --
701 CREATE TABLE /*_*/content (
702
703 -- ID of the content object
704 content_id bigint unsigned PRIMARY KEY AUTO_INCREMENT,
705
706 -- Nominal size of the content object (not necessarily of the serialized blob)
707 content_size int unsigned NOT NULL,
708
709 -- Nominal hash of the content object (not necessarily of the serialized blob)
710 content_sha1 varbinary(32) NOT NULL,
711
712 -- reference to model_id
713 content_model smallint unsigned NOT NULL,
714
715 -- URL-like address of the content blob
716 content_address varbinary(255) NOT NULL
717 ) /*$wgDBTableOptions*/;
718
719 --
720 -- Normalization table for role names
721 --
722 CREATE TABLE /*_*/slot_roles (
723 role_id smallint PRIMARY KEY AUTO_INCREMENT,
724 role_name varbinary(64) NOT NULL
725 ) /*$wgDBTableOptions*/;
726
727 -- Index for looking of the internal ID of for a name
728 CREATE UNIQUE INDEX /*i*/role_name ON /*_*/slot_roles (role_name);
729
730 --
731 -- Normalization table for content model names
732 --
733 CREATE TABLE /*_*/content_models (
734 model_id smallint PRIMARY KEY AUTO_INCREMENT,
735 model_name varbinary(64) NOT NULL
736 ) /*$wgDBTableOptions*/;
737
738 -- Index for looking of the internal ID of for a name
739 CREATE UNIQUE INDEX /*i*/model_name ON /*_*/content_models (model_name);
740
741 --
742 -- Track page-to-page hyperlinks within the wiki.
743 --
744 CREATE TABLE /*_*/pagelinks (
745 -- Key to the page_id of the page containing the link.
746 pl_from int unsigned NOT NULL default 0,
747 -- Namespace for this page
748 pl_from_namespace int NOT NULL default 0,
749
750 -- Key to page_namespace/page_title of the target page.
751 -- The target page may or may not exist, and due to renames
752 -- and deletions may refer to different page records as time
753 -- goes by.
754 pl_namespace int NOT NULL default 0,
755 pl_title varchar(255) binary NOT NULL default '',
756 PRIMARY KEY (pl_from,pl_namespace,pl_title)
757 ) /*$wgDBTableOptions*/;
758
759 -- Reverse index, for Special:Whatlinkshere
760 CREATE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from);
761
762 -- Index for Special:Whatlinkshere with namespace filter
763 CREATE INDEX /*i*/pl_backlinks_namespace ON /*_*/pagelinks (pl_from_namespace,pl_namespace,pl_title,pl_from);
764
765
766 --
767 -- Track template inclusions.
768 --
769 CREATE TABLE /*_*/templatelinks (
770 -- Key to the page_id of the page containing the link.
771 tl_from int unsigned NOT NULL default 0,
772 -- Namespace for this page
773 tl_from_namespace int NOT NULL default 0,
774
775 -- Key to page_namespace/page_title of the target page.
776 -- The target page may or may not exist, and due to renames
777 -- and deletions may refer to different page records as time
778 -- goes by.
779 tl_namespace int NOT NULL default 0,
780 tl_title varchar(255) binary NOT NULL default '',
781 PRIMARY KEY (tl_from,tl_namespace,tl_title)
782 ) /*$wgDBTableOptions*/;
783
784 -- Reverse index, for Special:Whatlinkshere
785 CREATE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from);
786
787 -- Index for Special:Whatlinkshere with namespace filter
788 CREATE INDEX /*i*/tl_backlinks_namespace ON /*_*/templatelinks (tl_from_namespace,tl_namespace,tl_title,tl_from);
789
790
791 --
792 -- Track links to images *used inline*
793 -- We don't distinguish live from broken links here, so
794 -- they do not need to be changed on upload/removal.
795 --
796 CREATE TABLE /*_*/imagelinks (
797 -- Key to page_id of the page containing the image / media link.
798 il_from int unsigned NOT NULL default 0,
799 -- Namespace for this page
800 il_from_namespace int NOT NULL default 0,
801
802 -- Filename of target image.
803 -- This is also the page_title of the file's description page;
804 -- all such pages are in namespace 6 (NS_FILE).
805 il_to varchar(255) binary NOT NULL default '',
806 PRIMARY KEY (il_from,il_to)
807 ) /*$wgDBTableOptions*/;
808
809 -- Reverse index, for Special:Whatlinkshere and file description page local usage
810 CREATE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from);
811
812 -- Index for Special:Whatlinkshere with namespace filter
813 CREATE INDEX /*i*/il_backlinks_namespace ON /*_*/imagelinks (il_from_namespace,il_to,il_from);
814
815
816 --
817 -- Track category inclusions *used inline*
818 -- This tracks a single level of category membership
819 --
820 CREATE TABLE /*_*/categorylinks (
821 -- Key to page_id of the page defined as a category member.
822 cl_from int unsigned NOT NULL default 0,
823
824 -- Name of the category.
825 -- This is also the page_title of the category's description page;
826 -- all such pages are in namespace 14 (NS_CATEGORY).
827 cl_to varchar(255) binary NOT NULL default '',
828
829 -- A binary string obtained by applying a sortkey generation algorithm
830 -- (Collation::getSortKey()) to page_title, or cl_sortkey_prefix . "\n"
831 -- . page_title if cl_sortkey_prefix is nonempty.
832 cl_sortkey varbinary(230) NOT NULL default '',
833
834 -- A prefix for the raw sortkey manually specified by the user, either via
835 -- [[Category:Foo|prefix]] or {{defaultsort:prefix}}. If nonempty, it's
836 -- concatenated with a line break followed by the page title before the sortkey
837 -- conversion algorithm is run. We store this so that we can update
838 -- collations without reparsing all pages.
839 -- Note: If you change the length of this field, you also need to change
840 -- code in LinksUpdate.php. See T27254.
841 cl_sortkey_prefix varchar(255) binary NOT NULL default '',
842
843 -- This isn't really used at present. Provided for an optional
844 -- sorting method by approximate addition time.
845 cl_timestamp timestamp NOT NULL,
846
847 -- Stores $wgCategoryCollation at the time cl_sortkey was generated. This
848 -- can be used to install new collation versions, tracking which rows are not
849 -- yet updated. '' means no collation, this is a legacy row that needs to be
850 -- updated by updateCollation.php. In the future, it might be possible to
851 -- specify different collations per category.
852 cl_collation varbinary(32) NOT NULL default '',
853
854 -- Stores whether cl_from is a category, file, or other page, so we can
855 -- paginate the three categories separately. This never has to be updated
856 -- after the page is created, since none of these page types can be moved to
857 -- any other.
858 cl_type ENUM('page', 'subcat', 'file') NOT NULL default 'page',
859 PRIMARY KEY (cl_from,cl_to)
860 ) /*$wgDBTableOptions*/;
861
862
863 -- We always sort within a given category, and within a given type. FIXME:
864 -- Formerly this index didn't cover cl_type (since that didn't exist), so old
865 -- callers won't be using an index: fix this?
866 CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_type,cl_sortkey,cl_from);
867
868 -- Used by the API (and some extensions)
869 CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);
870
871 -- Used when updating collation (e.g. updateCollation.php)
872 CREATE INDEX /*i*/cl_collation_ext ON /*_*/categorylinks (cl_collation, cl_to, cl_type, cl_from);
873
874 --
875 -- Track all existing categories. Something is a category if 1) it has an entry
876 -- somewhere in categorylinks, or 2) it has a description page. Categories
877 -- might not have corresponding pages, so they need to be tracked separately.
878 --
879 CREATE TABLE /*_*/category (
880 -- Primary key
881 cat_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
882
883 -- Name of the category, in the same form as page_title (with underscores).
884 -- If there is a category page corresponding to this category, by definition,
885 -- it has this name (in the Category namespace).
886 cat_title varchar(255) binary NOT NULL,
887
888 -- The numbers of member pages (including categories and media), subcatego-
889 -- ries, and Image: namespace members, respectively. These are signed to
890 -- make underflow more obvious. We make the first number include the second
891 -- two for better sorting: subtracting for display is easy, adding for order-
892 -- ing is not.
893 cat_pages int signed NOT NULL default 0,
894 cat_subcats int signed NOT NULL default 0,
895 cat_files int signed NOT NULL default 0
896 ) /*$wgDBTableOptions*/;
897
898 CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);
899
900 -- For Special:Mostlinkedcategories
901 CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);
902
903
904 --
905 -- Track links to external URLs
906 --
907 CREATE TABLE /*_*/externallinks (
908 -- Primary key
909 el_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
910
911 -- page_id of the referring page
912 el_from int unsigned NOT NULL default 0,
913
914 -- The URL
915 el_to blob NOT NULL,
916
917 -- In the case of HTTP URLs, this is the URL with any username or password
918 -- removed, and with the labels in the hostname reversed and converted to
919 -- lower case. An extra dot is added to allow for matching of either
920 -- example.com or *.example.com in a single scan.
921 -- Example:
922 -- http://user:password@sub.example.com/page.html
923 -- becomes
924 -- http://com.example.sub./page.html
925 -- which allows for fast searching for all pages under example.com with the
926 -- clause:
927 -- WHERE el_index LIKE 'http://com.example.%'
928 el_index blob NOT NULL,
929
930 -- This is el_index truncated to 60 bytes to allow for sortable queries that
931 -- aren't supported by a partial index.
932 -- @todo Drop the default once this is deployed everywhere and code is populating it.
933 el_index_60 varbinary(60) NOT NULL default ''
934 ) /*$wgDBTableOptions*/;
935
936 -- Forward index, for page edit, save
937 CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from, el_to(40));
938
939 -- Index for Special:LinkSearch exact search
940 CREATE INDEX /*i*/el_to ON /*_*/externallinks (el_to(60), el_from);
941
942 -- For Special:LinkSearch wildcard search
943 CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index(60));
944
945 -- For Special:LinkSearch wildcard search with efficient paging by el_id
946 CREATE INDEX /*i*/el_index_60 ON /*_*/externallinks (el_index_60, el_id);
947 CREATE INDEX /*i*/el_from_index_60 ON /*_*/externallinks (el_from, el_index_60, el_id);
948
949 --
950 -- Track interlanguage links
951 --
952 CREATE TABLE /*_*/langlinks (
953 -- page_id of the referring page
954 ll_from int unsigned NOT NULL default 0,
955
956 -- Language code of the target
957 ll_lang varbinary(20) NOT NULL default '',
958
959 -- Title of the target, including namespace
960 ll_title varchar(255) binary NOT NULL default '',
961 PRIMARY KEY (ll_from,ll_lang)
962 ) /*$wgDBTableOptions*/;
963
964 -- Index for ApiQueryLangbacklinks
965 CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);
966
967
968 --
969 -- Track inline interwiki links
970 --
971 CREATE TABLE /*_*/iwlinks (
972 -- page_id of the referring page
973 iwl_from int unsigned NOT NULL default 0,
974
975 -- Interwiki prefix code of the target
976 iwl_prefix varbinary(20) NOT NULL default '',
977
978 -- Title of the target, including namespace
979 iwl_title varchar(255) binary NOT NULL default '',
980 PRIMARY KEY (iwl_from,iwl_prefix,iwl_title)
981 ) /*$wgDBTableOptions*/;
982
983 -- Index for ApiQueryIWBacklinks
984 CREATE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from);
985
986 -- Index for ApiQueryIWLinks
987 CREATE INDEX /*i*/iwl_prefix_from_title ON /*_*/iwlinks (iwl_prefix, iwl_from, iwl_title);
988
989
990 --
991 -- Contains a single row with some aggregate info
992 -- on the state of the site.
993 --
994 CREATE TABLE /*_*/site_stats (
995 -- The single row should contain 1 here.
996 ss_row_id int unsigned NOT NULL PRIMARY KEY,
997
998 -- Total number of edits performed.
999 ss_total_edits bigint unsigned default NULL,
1000
1001 -- See SiteStatsInit::articles().
1002 ss_good_articles bigint unsigned default NULL,
1003
1004 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page.
1005 ss_total_pages bigint unsigned default NULL,
1006
1007 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user.
1008 ss_users bigint unsigned default NULL,
1009
1010 -- Number of users that still edit.
1011 ss_active_users bigint unsigned default NULL,
1012
1013 -- Number of images, equivalent to SELECT COUNT(*) FROM image.
1014 ss_images bigint unsigned default NULL
1015 ) /*$wgDBTableOptions*/;
1016
1017 --
1018 -- The internet is full of jerks, alas. Sometimes it's handy
1019 -- to block a vandal or troll account.
1020 --
1021 CREATE TABLE /*_*/ipblocks (
1022 -- Primary key, introduced for privacy.
1023 ipb_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
1024
1025 -- Blocked IP address in dotted-quad form or user name.
1026 ipb_address tinyblob NOT NULL,
1027
1028 -- Blocked user ID or 0 for IP blocks.
1029 ipb_user int unsigned NOT NULL default 0,
1030
1031 -- User ID who made the block.
1032 ipb_by int unsigned NOT NULL default 0, -- Deprecated in favor of ipb_by_actor
1033
1034 -- User name of blocker
1035 ipb_by_text varchar(255) binary NOT NULL default '', -- Deprecated in favor of ipb_by_actor
1036
1037 -- Actor who made the block.
1038 ipb_by_actor bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that ipb_by/ipb_by_text should be used)
1039
1040 -- Text comment made by blocker. Deprecated in favor of ipb_reason_id
1041 ipb_reason varbinary(767) NOT NULL default '',
1042
1043 -- Key to comment_id. Text comment made by blocker.
1044 -- ("DEFAULT 0" is temporary, signaling that ipb_reason should be used)
1045 ipb_reason_id bigint unsigned NOT NULL DEFAULT 0,
1046
1047 -- Creation (or refresh) date in standard YMDHMS form.
1048 -- IP blocks expire automatically.
1049 ipb_timestamp binary(14) NOT NULL default '',
1050
1051 -- Indicates that the IP address was banned because a banned
1052 -- user accessed a page through it. If this is 1, ipb_address
1053 -- will be hidden, and the block identified by block ID number.
1054 ipb_auto bool NOT NULL default 0,
1055
1056 -- If set to 1, block applies only to logged-out users
1057 ipb_anon_only bool NOT NULL default 0,
1058
1059 -- Block prevents account creation from matching IP addresses
1060 ipb_create_account bool NOT NULL default 1,
1061
1062 -- Block triggers autoblocks
1063 ipb_enable_autoblock bool NOT NULL default '1',
1064
1065 -- Time at which the block will expire.
1066 -- May be "infinity"
1067 ipb_expiry varbinary(14) NOT NULL default '',
1068
1069 -- Start and end of an address range, in hexadecimal
1070 -- Size chosen to allow IPv6
1071 -- FIXME: these fields were originally blank for single-IP blocks,
1072 -- but now they are populated. No migration was ever done. They
1073 -- should be fixed to be blank again for such blocks (T51504).
1074 ipb_range_start tinyblob NOT NULL,
1075 ipb_range_end tinyblob NOT NULL,
1076
1077 -- Flag for entries hidden from users and Sysops
1078 ipb_deleted bool NOT NULL default 0,
1079
1080 -- Block prevents user from accessing Special:Emailuser
1081 ipb_block_email bool NOT NULL default 0,
1082
1083 -- Block allows user to edit their own talk page
1084 ipb_allow_usertalk bool NOT NULL default 0,
1085
1086 -- ID of the block that caused this block to exist
1087 -- Autoblocks set this to the original block
1088 -- so that the original block being deleted also
1089 -- deletes the autoblocks
1090 ipb_parent_block_id int default NULL
1091
1092 ) /*$wgDBTableOptions*/;
1093
1094 -- Unique index to support "user already blocked" messages
1095 -- Any new options which prevent collisions should be included
1096 CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only);
1097
1098 -- For querying whether a logged-in user is blocked
1099 CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
1100
1101 -- For querying whether an IP address is in any range
1102 CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start(8), ipb_range_end(8));
1103
1104 -- Index for Special:BlockList
1105 CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
1106
1107 -- Index for table pruning
1108 CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
1109
1110 -- Index for removing autoblocks when a parent block is removed
1111 CREATE INDEX /*i*/ipb_parent_block_id ON /*_*/ipblocks (ipb_parent_block_id);
1112
1113
1114 --
1115 -- Uploaded images and other files.
1116 --
1117 CREATE TABLE /*_*/image (
1118 -- Filename.
1119 -- This is also the title of the associated description page,
1120 -- which will be in namespace 6 (NS_FILE).
1121 img_name varchar(255) binary NOT NULL default '' PRIMARY KEY,
1122
1123 -- File size in bytes.
1124 img_size int unsigned NOT NULL default 0,
1125
1126 -- For images, size in pixels.
1127 img_width int NOT NULL default 0,
1128 img_height int NOT NULL default 0,
1129
1130 -- Extracted Exif metadata stored as a serialized PHP array.
1131 img_metadata mediumblob NOT NULL,
1132
1133 -- For images, bits per pixel if known.
1134 img_bits int NOT NULL default 0,
1135
1136 -- Media type as defined by the MEDIATYPE_xxx constants
1137 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE", "3D") default NULL,
1138
1139 -- major part of a MIME media type as defined by IANA
1140 -- see https://www.iana.org/assignments/media-types/
1141 -- for "chemical" cf. http://dx.doi.org/10.1021/ci9803233 by the ACS
1142 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown",
1143
1144 -- minor part of a MIME media type as defined by IANA
1145 -- the minor parts are not required to adher to any standard
1146 -- but should be consistent throughout the database
1147 -- see https://www.iana.org/assignments/media-types/
1148 img_minor_mime varbinary(100) NOT NULL default "unknown",
1149
1150 -- Description field as entered by the uploader.
1151 -- This is displayed in image upload history and logs.
1152 -- Deprecated in favor of image_comment_temp.imgcomment_description_id.
1153 img_description varbinary(767) NOT NULL default '',
1154
1155 -- user_id and user_name of uploader.
1156 -- Deprecated in favor of img_actor.
1157 img_user int unsigned NOT NULL default 0,
1158 img_user_text varchar(255) binary NOT NULL DEFAULT '',
1159
1160 -- actor_id of the uploader.
1161 -- ("DEFAULT 0" is temporary, signaling that img_user/img_user_text should be used)
1162 img_actor bigint unsigned NOT NULL DEFAULT 0,
1163
1164 -- Time of the upload.
1165 img_timestamp varbinary(14) NOT NULL default '',
1166
1167 -- SHA-1 content hash in base-36
1168 img_sha1 varbinary(32) NOT NULL default ''
1169 ) /*$wgDBTableOptions*/;
1170
1171 -- Used by Special:Newimages and ApiQueryAllImages
1172 CREATE INDEX /*i*/img_user_timestamp ON /*_*/image (img_user,img_timestamp);
1173 CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
1174 CREATE INDEX /*i*/img_actor_timestamp ON /*_*/image (img_actor,img_timestamp);
1175 -- Used by Special:ListFiles for sort-by-size
1176 CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
1177 -- Used by Special:Newimages and Special:ListFiles
1178 CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
1179 -- Used in API and duplicate search
1180 CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1(10));
1181 -- Used to get media of one type
1182 CREATE INDEX /*i*/img_media_mime ON /*_*/image (img_media_type,img_major_mime,img_minor_mime);
1183
1184 --
1185 -- Temporary table to avoid blocking on an alter of image.
1186 --
1187 -- On large wikis like Wikimedia Commons, altering the image table is a
1188 -- months-long process. This table is being created to avoid such an alter, and
1189 -- will be merged back into image in the future.
1190 --
1191 CREATE TABLE /*_*/image_comment_temp (
1192 -- Key to img_name (ugh)
1193 imgcomment_name varchar(255) binary NOT NULL,
1194 -- Key to comment_id
1195 imgcomment_description_id bigint unsigned NOT NULL,
1196 PRIMARY KEY (imgcomment_name, imgcomment_description_id)
1197 ) /*$wgDBTableOptions*/;
1198 -- Ensure uniqueness
1199 CREATE UNIQUE INDEX /*i*/imgcomment_name ON /*_*/image_comment_temp (imgcomment_name);
1200
1201
1202 --
1203 -- Previous revisions of uploaded files.
1204 -- Awkwardly, image rows have to be moved into
1205 -- this table at re-upload time.
1206 --
1207 CREATE TABLE /*_*/oldimage (
1208 -- Base filename: key to image.img_name
1209 oi_name varchar(255) binary NOT NULL default '',
1210
1211 -- Filename of the archived file.
1212 -- This is generally a timestamp and '!' prepended to the base name.
1213 oi_archive_name varchar(255) binary NOT NULL default '',
1214
1215 -- Other fields as in image...
1216 oi_size int unsigned NOT NULL default 0,
1217 oi_width int NOT NULL default 0,
1218 oi_height int NOT NULL default 0,
1219 oi_bits int NOT NULL default 0,
1220 oi_description varbinary(767) NOT NULL default '', -- Deprecated.
1221 oi_description_id bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that oi_description should be used)
1222 oi_user int unsigned NOT NULL default 0, -- Deprecated in favor of oi_actor
1223 oi_user_text varchar(255) binary NOT NULL DEFAULT '', -- Deprecated in favor of oi_actor
1224 oi_actor bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that oi_user/oi_user_text should be used)
1225 oi_timestamp binary(14) NOT NULL default '',
1226
1227 oi_metadata mediumblob NOT NULL,
1228 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE", "3D") default NULL,
1229 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown",
1230 oi_minor_mime varbinary(100) NOT NULL default "unknown",
1231 oi_deleted tinyint unsigned NOT NULL default 0,
1232 oi_sha1 varbinary(32) NOT NULL default ''
1233 ) /*$wgDBTableOptions*/;
1234
1235 CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
1236 CREATE INDEX /*i*/oi_actor_timestamp ON /*_*/oldimage (oi_actor,oi_timestamp);
1237 CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
1238 -- oi_archive_name truncated to 14 to avoid key length overflow
1239 CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name(14));
1240 CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1(10));
1241
1242
1243 --
1244 -- Record of deleted file data
1245 --
1246 CREATE TABLE /*_*/filearchive (
1247 -- Unique row id
1248 fa_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
1249
1250 -- Original base filename; key to image.img_name, page.page_title, etc
1251 fa_name varchar(255) binary NOT NULL default '',
1252
1253 -- Filename of archived file, if an old revision
1254 fa_archive_name varchar(255) binary default '',
1255
1256 -- Which storage bin (directory tree or object store) the file data
1257 -- is stored in. Should be 'deleted' for files that have been deleted;
1258 -- any other bin is not yet in use.
1259 fa_storage_group varbinary(16),
1260
1261 -- SHA-1 of the file contents plus extension, used as a key for storage.
1262 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
1263 --
1264 -- If NULL, the file was missing at deletion time or has been purged
1265 -- from the archival storage.
1266 fa_storage_key varbinary(64) default '',
1267
1268 -- Deletion information, if this file is deleted.
1269 fa_deleted_user int,
1270 fa_deleted_timestamp binary(14) default '',
1271 fa_deleted_reason varbinary(767) default '', -- Deprecated
1272 fa_deleted_reason_id bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that fa_deleted_reason should be used)
1273
1274 -- Duped fields from image
1275 fa_size int unsigned default 0,
1276 fa_width int default 0,
1277 fa_height int default 0,
1278 fa_metadata mediumblob,
1279 fa_bits int default 0,
1280 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE", "3D") default NULL,
1281 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") default "unknown",
1282 fa_minor_mime varbinary(100) default "unknown",
1283 fa_description varbinary(767) default '', -- Deprecated
1284 fa_description_id bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that fa_description should be used)
1285 fa_user int unsigned default 0, -- Deprecated in favor of fa_actor
1286 fa_user_text varchar(255) binary DEFAULT '', -- Deprecated in favor of fa_actor
1287 fa_actor bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that fa_user/fa_user_text should be used)
1288 fa_timestamp binary(14) default '',
1289
1290 -- Visibility of deleted revisions, bitfield
1291 fa_deleted tinyint unsigned NOT NULL default 0,
1292
1293 -- sha1 hash of file content
1294 fa_sha1 varbinary(32) NOT NULL default ''
1295 ) /*$wgDBTableOptions*/;
1296
1297 -- pick out by image name
1298 CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
1299 -- pick out dupe files
1300 CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
1301 -- sort by deletion time
1302 CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
1303 -- sort by uploader
1304 CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
1305 CREATE INDEX /*i*/fa_actor_timestamp ON /*_*/filearchive (fa_actor,fa_timestamp);
1306 -- find file by sha1, 10 bytes will be enough for hashes to be indexed
1307 CREATE INDEX /*i*/fa_sha1 ON /*_*/filearchive (fa_sha1(10));
1308
1309
1310 --
1311 -- Store information about newly uploaded files before they're
1312 -- moved into the actual filestore
1313 --
1314 CREATE TABLE /*_*/uploadstash (
1315 us_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1316
1317 -- the user who uploaded the file.
1318 us_user int unsigned NOT NULL,
1319
1320 -- file key. this is how applications actually search for the file.
1321 -- this might go away, or become the primary key.
1322 us_key varchar(255) NOT NULL,
1323
1324 -- the original path
1325 us_orig_path varchar(255) NOT NULL,
1326
1327 -- the temporary path at which the file is actually stored
1328 us_path varchar(255) NOT NULL,
1329
1330 -- which type of upload the file came from (sometimes)
1331 us_source_type varchar(50),
1332
1333 -- the date/time on which the file was added
1334 us_timestamp varbinary(14) NOT NULL,
1335
1336 us_status varchar(50) NOT NULL,
1337
1338 -- chunk counter starts at 0, current offset is stored in us_size
1339 us_chunk_inx int unsigned NULL,
1340
1341 -- Serialized file properties from FSFile::getProps()
1342 us_props blob,
1343
1344 -- file size in bytes
1345 us_size int unsigned NOT NULL,
1346 -- this hash comes from FSFile::getSha1Base36(), and is 31 characters
1347 us_sha1 varchar(31) NOT NULL,
1348 us_mime varchar(255),
1349 -- Media type as defined by the MEDIATYPE_xxx constants, should duplicate definition in the image table
1350 us_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE", "3D") default NULL,
1351 -- image-specific properties
1352 us_image_width int unsigned,
1353 us_image_height int unsigned,
1354 us_image_bits smallint unsigned
1355
1356 ) /*$wgDBTableOptions*/;
1357
1358 -- sometimes there's a delete for all of a user's stuff.
1359 CREATE INDEX /*i*/us_user ON /*_*/uploadstash (us_user);
1360 -- pick out files by key, enforce key uniqueness
1361 CREATE UNIQUE INDEX /*i*/us_key ON /*_*/uploadstash (us_key);
1362 -- the abandoned upload cleanup script needs this
1363 CREATE INDEX /*i*/us_timestamp ON /*_*/uploadstash (us_timestamp);
1364
1365
1366 --
1367 -- Primarily a summary table for Special:Recentchanges,
1368 -- this table contains some additional info on edits from
1369 -- the last few days, see Article::editUpdates()
1370 --
1371 CREATE TABLE /*_*/recentchanges (
1372 rc_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
1373 rc_timestamp varbinary(14) NOT NULL default '',
1374
1375 -- As in revision
1376 rc_user int unsigned NOT NULL default 0, -- Deprecated in favor of rc_actor
1377 rc_user_text varchar(255) binary NOT NULL DEFAULT '', -- Deprecated in favor of rc_actor
1378 rc_actor bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that rc_user/rc_user_text should be used)
1379
1380 -- When pages are renamed, their RC entries do _not_ change.
1381 rc_namespace int NOT NULL default 0,
1382 rc_title varchar(255) binary NOT NULL default '',
1383
1384 -- as in revision...
1385 rc_comment varbinary(767) NOT NULL default '', -- Deprecated.
1386 rc_comment_id bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that rc_comment should be used)
1387 rc_minor tinyint unsigned NOT NULL default 0,
1388
1389 -- Edits by user accounts with the 'bot' rights key are
1390 -- marked with a 1 here, and will be hidden from the
1391 -- default view.
1392 rc_bot tinyint unsigned NOT NULL default 0,
1393
1394 -- Set if this change corresponds to a page creation
1395 rc_new tinyint unsigned NOT NULL default 0,
1396
1397 -- Key to page_id (was cur_id prior to 1.5).
1398 -- This will keep links working after moves while
1399 -- retaining the at-the-time name in the changes list.
1400 rc_cur_id int unsigned NOT NULL default 0,
1401
1402 -- rev_id of the given revision
1403 rc_this_oldid int unsigned NOT NULL default 0,
1404
1405 -- rev_id of the prior revision, for generating diff links.
1406 rc_last_oldid int unsigned NOT NULL default 0,
1407
1408 -- The type of change entry (RC_EDIT,RC_NEW,RC_LOG,RC_EXTERNAL)
1409 rc_type tinyint unsigned NOT NULL default 0,
1410
1411 -- The source of the change entry (replaces rc_type)
1412 -- default of '' is temporary, needed for initial migration
1413 rc_source varchar(16) binary not null default '',
1414
1415 -- If the Recent Changes Patrol option is enabled,
1416 -- users may mark edits as having been reviewed to
1417 -- remove a warning flag on the RC list.
1418 -- A value of 1 indicates the page has been reviewed.
1419 rc_patrolled tinyint unsigned NOT NULL default 0,
1420
1421 -- Recorded IP address the edit was made from, if the
1422 -- $wgPutIPinRC option is enabled.
1423 rc_ip varbinary(40) NOT NULL default '',
1424
1425 -- Text length in characters before
1426 -- and after the edit
1427 rc_old_len int,
1428 rc_new_len int,
1429
1430 -- Visibility of recent changes items, bitfield
1431 rc_deleted tinyint unsigned NOT NULL default 0,
1432
1433 -- Value corresponding to log_id, specific log entries
1434 rc_logid int unsigned NOT NULL default 0,
1435 -- Store log type info here, or null
1436 rc_log_type varbinary(255) NULL default NULL,
1437 -- Store log action or null
1438 rc_log_action varbinary(255) NULL default NULL,
1439 -- Log params
1440 rc_params blob NULL
1441 ) /*$wgDBTableOptions*/;
1442
1443 -- Special:Recentchanges
1444 CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
1445
1446 -- Special:Watchlist
1447 CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
1448
1449 -- Special:Recentchangeslinked when finding changes in pages linked from a page
1450 CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
1451
1452 -- Special:Newpages
1453 CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
1454
1455 -- Blank unless $wgPutIPinRC=true (false at WMF), possibly used by extensions,
1456 -- but mostly replaced by CheckUser.
1457 CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
1458
1459 -- Probably intended for Special:NewPages namespace filter
1460 CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
1461 CREATE INDEX /*i*/rc_ns_actor ON /*_*/recentchanges (rc_namespace, rc_actor);
1462
1463 -- SiteStats active user count, Special:ActiveUsers, Special:NewPages user filter
1464 CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);
1465 CREATE INDEX /*i*/rc_actor ON /*_*/recentchanges (rc_actor, rc_timestamp);
1466
1467 -- ApiQueryRecentChanges (T140108)
1468 CREATE INDEX /*i*/rc_name_type_patrolled_timestamp ON /*_*/recentchanges (rc_namespace, rc_type, rc_patrolled, rc_timestamp);
1469
1470
1471 CREATE TABLE /*_*/watchlist (
1472 wl_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1473 -- Key to user.user_id
1474 wl_user int unsigned NOT NULL,
1475
1476 -- Key to page_namespace/page_title
1477 -- Note that users may watch pages which do not exist yet,
1478 -- or existed in the past but have been deleted.
1479 wl_namespace int NOT NULL default 0,
1480 wl_title varchar(255) binary NOT NULL default '',
1481
1482 -- Timestamp used to send notification e-mails and show "updated since last visit" markers on
1483 -- history and recent changes / watchlist. Set to NULL when the user visits the latest revision
1484 -- of the page, which means that they should be sent an e-mail on the next change.
1485 wl_notificationtimestamp varbinary(14)
1486
1487 ) /*$wgDBTableOptions*/;
1488
1489 -- Special:Watchlist
1490 CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
1491
1492 -- Special:Movepage (WatchedItemStore::duplicateEntry)
1493 CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);
1494
1495 -- ApiQueryWatchlistRaw changed filter
1496 CREATE INDEX /*i*/wl_user_notificationtimestamp ON /*_*/watchlist (wl_user, wl_notificationtimestamp);
1497
1498
1499 --
1500 -- When using the default MySQL search backend, page titles
1501 -- and text are munged to strip markup, do Unicode case folding,
1502 -- and prepare the result for MySQL's fulltext index.
1503 --
1504 -- This table must be MyISAM; InnoDB does not support the needed
1505 -- fulltext index.
1506 --
1507 CREATE TABLE /*_*/searchindex (
1508 -- Key to page_id
1509 si_page int unsigned NOT NULL,
1510
1511 -- Munged version of title
1512 si_title varchar(255) NOT NULL default '',
1513
1514 -- Munged version of body text
1515 si_text mediumtext NOT NULL
1516 ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
1517
1518 CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
1519 CREATE FULLTEXT INDEX /*i*/si_title ON /*_*/searchindex (si_title);
1520 CREATE FULLTEXT INDEX /*i*/si_text ON /*_*/searchindex (si_text);
1521
1522
1523 --
1524 -- Recognized interwiki link prefixes
1525 --
1526 CREATE TABLE /*_*/interwiki (
1527 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
1528 iw_prefix varchar(32) NOT NULL,
1529
1530 -- The URL of the wiki, with "$1" as a placeholder for an article name.
1531 -- Any spaces in the name will be transformed to underscores before
1532 -- insertion.
1533 iw_url blob NOT NULL,
1534
1535 -- The URL of the file api.php
1536 iw_api blob NOT NULL,
1537
1538 -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' ))
1539 iw_wikiid varchar(64) NOT NULL,
1540
1541 -- A boolean value indicating whether the wiki is in this project
1542 -- (used, for example, to detect redirect loops)
1543 iw_local bool NOT NULL,
1544
1545 -- Boolean value indicating whether interwiki transclusions are allowed.
1546 iw_trans tinyint NOT NULL default 0
1547 ) /*$wgDBTableOptions*/;
1548
1549 CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);
1550
1551
1552 --
1553 -- Used for caching expensive grouped queries
1554 --
1555 CREATE TABLE /*_*/querycache (
1556 -- A key name, generally the base name of of the special page.
1557 qc_type varbinary(32) NOT NULL,
1558
1559 -- Some sort of stored value. Sizes, counts...
1560 qc_value int unsigned NOT NULL default 0,
1561
1562 -- Target namespace+title
1563 qc_namespace int NOT NULL default 0,
1564 qc_title varchar(255) binary NOT NULL default ''
1565 ) /*$wgDBTableOptions*/;
1566
1567 CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);
1568
1569
1570 --
1571 -- For a few generic cache operations if not using Memcached
1572 --
1573 CREATE TABLE /*_*/objectcache (
1574 keyname varbinary(255) NOT NULL default '' PRIMARY KEY,
1575 value mediumblob,
1576 exptime datetime
1577 ) /*$wgDBTableOptions*/;
1578 CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);
1579
1580
1581 --
1582 -- Cache of interwiki transclusion
1583 --
1584 CREATE TABLE /*_*/transcache (
1585 tc_url varbinary(255) NOT NULL PRIMARY KEY,
1586 tc_contents text,
1587 tc_time binary(14) NOT NULL
1588 ) /*$wgDBTableOptions*/;
1589
1590
1591 CREATE TABLE /*_*/logging (
1592 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1593 log_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1594
1595 -- Symbolic keys for the general log type and the action type
1596 -- within the log. The output format will be controlled by the
1597 -- action field, but only the type controls categorization.
1598 log_type varbinary(32) NOT NULL default '',
1599 log_action varbinary(32) NOT NULL default '',
1600
1601 -- Timestamp. Duh.
1602 log_timestamp binary(14) NOT NULL default '19700101000000',
1603
1604 -- The user who performed this action; key to user_id
1605 log_user int unsigned NOT NULL default 0, -- Deprecated in favor of log_actor
1606
1607 -- Name of the user who performed this action
1608 log_user_text varchar(255) binary NOT NULL default '', -- Deprecated in favor of log_actor
1609
1610 -- The actor who performed this action
1611 log_actor bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that log_user/log_user_text should be used)
1612
1613 -- Key to the page affected. Where a user is the target,
1614 -- this will point to the user page.
1615 log_namespace int NOT NULL default 0,
1616 log_title varchar(255) binary NOT NULL default '',
1617 log_page int unsigned NULL,
1618
1619 -- Freeform text. Interpreted as edit history comments.
1620 -- Deprecated in favor of log_comment_id.
1621 log_comment varbinary(767) NOT NULL default '',
1622
1623 -- Key to comment_id. Comment summarizing the change.
1624 -- ("DEFAULT 0" is temporary, signaling that log_comment should be used)
1625 log_comment_id bigint unsigned NOT NULL DEFAULT 0,
1626
1627 -- miscellaneous parameters:
1628 -- LF separated list (old system) or serialized PHP array (new system)
1629 log_params blob NOT NULL,
1630
1631 -- rev_deleted for logs
1632 log_deleted tinyint unsigned NOT NULL default 0
1633 ) /*$wgDBTableOptions*/;
1634
1635 -- Special:Log type filter
1636 CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
1637
1638 -- Special:Log performer filter
1639 CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
1640 CREATE INDEX /*i*/actor_time ON /*_*/logging (log_actor, log_timestamp);
1641
1642 -- Special:Log title filter, log extract
1643 CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
1644
1645 -- Special:Log unfiltered
1646 CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
1647
1648 -- Special:Log filter by performer and type
1649 CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp);
1650 CREATE INDEX /*i*/log_actor_type_time ON /*_*/logging (log_actor, log_type, log_timestamp);
1651
1652 -- Apparently just used for a few maintenance pages (findMissingFiles.php, Flow).
1653 -- Could be removed?
1654 CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp);
1655
1656 -- Special:Log action filter
1657 CREATE INDEX /*i*/type_action ON /*_*/logging (log_type, log_action, log_timestamp);
1658
1659 -- Special:Log filter by type and anonymous performer
1660 CREATE INDEX /*i*/log_user_text_type_time ON /*_*/logging (log_user_text, log_type, log_timestamp);
1661
1662 -- Special:Log filter by anonymous performer
1663 CREATE INDEX /*i*/log_user_text_time ON /*_*/logging (log_user_text, log_timestamp);
1664
1665
1666 CREATE TABLE /*_*/log_search (
1667 -- The type of ID (rev ID, log ID, rev timestamp, username)
1668 ls_field varbinary(32) NOT NULL,
1669 -- The value of the ID
1670 ls_value varchar(255) NOT NULL,
1671 -- Key to log_id
1672 ls_log_id int unsigned NOT NULL default 0,
1673 PRIMARY KEY (ls_field,ls_value,ls_log_id)
1674 ) /*$wgDBTableOptions*/;
1675 CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);
1676
1677
1678 -- Jobs performed by parallel apache threads or a command-line daemon
1679 CREATE TABLE /*_*/job (
1680 job_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1681
1682 -- Command name
1683 -- Limited to 60 to prevent key length overflow
1684 job_cmd varbinary(60) NOT NULL default '',
1685
1686 -- Namespace and title to act on
1687 -- Should be 0 and '' if the command does not operate on a title
1688 job_namespace int NOT NULL,
1689 job_title varchar(255) binary NOT NULL,
1690
1691 -- Timestamp of when the job was inserted
1692 -- NULL for jobs added before addition of the timestamp
1693 job_timestamp varbinary(14) NULL default NULL,
1694
1695 -- Any other parameters to the command
1696 -- Stored as a PHP serialized array, or an empty string if there are no parameters
1697 job_params blob NOT NULL,
1698
1699 -- Random, non-unique, number used for job acquisition (for lock concurrency)
1700 job_random integer unsigned NOT NULL default 0,
1701
1702 -- The number of times this job has been locked
1703 job_attempts integer unsigned NOT NULL default 0,
1704
1705 -- Field that conveys process locks on rows via process UUIDs
1706 job_token varbinary(32) NOT NULL default '',
1707
1708 -- Timestamp when the job was locked
1709 job_token_timestamp varbinary(14) NULL default NULL,
1710
1711 -- Base 36 SHA1 of the job parameters relevant to detecting duplicates
1712 job_sha1 varbinary(32) NOT NULL default ''
1713 ) /*$wgDBTableOptions*/;
1714
1715 CREATE INDEX /*i*/job_sha1 ON /*_*/job (job_sha1);
1716 CREATE INDEX /*i*/job_cmd_token ON /*_*/job (job_cmd,job_token,job_random);
1717 CREATE INDEX /*i*/job_cmd_token_id ON /*_*/job (job_cmd,job_token,job_id);
1718 CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title, job_params(128));
1719 CREATE INDEX /*i*/job_timestamp ON /*_*/job (job_timestamp);
1720
1721
1722 -- Details of updates to cached special pages
1723 CREATE TABLE /*_*/querycache_info (
1724 -- Special page name
1725 -- Corresponds to a qc_type value
1726 qci_type varbinary(32) NOT NULL default '' PRIMARY KEY,
1727
1728 -- Timestamp of last update
1729 qci_timestamp binary(14) NOT NULL default '19700101000000'
1730 ) /*$wgDBTableOptions*/;
1731
1732
1733 -- For each redirect, this table contains exactly one row defining its target
1734 CREATE TABLE /*_*/redirect (
1735 -- Key to the page_id of the redirect page
1736 rd_from int unsigned NOT NULL default 0 PRIMARY KEY,
1737
1738 -- Key to page_namespace/page_title of the target page.
1739 -- The target page may or may not exist, and due to renames
1740 -- and deletions may refer to different page records as time
1741 -- goes by.
1742 rd_namespace int NOT NULL default 0,
1743 rd_title varchar(255) binary NOT NULL default '',
1744 rd_interwiki varchar(32) default NULL,
1745 rd_fragment varchar(255) binary default NULL
1746 ) /*$wgDBTableOptions*/;
1747
1748 CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);
1749
1750
1751 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1752 CREATE TABLE /*_*/querycachetwo (
1753 -- A key name, generally the base name of of the special page.
1754 qcc_type varbinary(32) NOT NULL,
1755
1756 -- Some sort of stored value. Sizes, counts...
1757 qcc_value int unsigned NOT NULL default 0,
1758
1759 -- Target namespace+title
1760 qcc_namespace int NOT NULL default 0,
1761 qcc_title varchar(255) binary NOT NULL default '',
1762
1763 -- Target namespace+title2
1764 qcc_namespacetwo int NOT NULL default 0,
1765 qcc_titletwo varchar(255) binary NOT NULL default ''
1766 ) /*$wgDBTableOptions*/;
1767
1768 CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
1769 CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
1770 CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
1771
1772
1773 -- Used for storing page restrictions (i.e. protection levels)
1774 CREATE TABLE /*_*/page_restrictions (
1775 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1776 pr_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1777 -- Page to apply restrictions to (Foreign Key to page).
1778 pr_page int NOT NULL,
1779 -- The protection type (edit, move, etc)
1780 pr_type varbinary(60) NOT NULL,
1781 -- The protection level (Sysop, autoconfirmed, etc)
1782 pr_level varbinary(60) NOT NULL,
1783 -- Whether or not to cascade the protection down to pages transcluded.
1784 pr_cascade tinyint NOT NULL,
1785 -- Field for future support of per-user restriction.
1786 pr_user int unsigned NULL,
1787 -- Field for time-limited protection.
1788 pr_expiry varbinary(14) NULL
1789 ) /*$wgDBTableOptions*/;
1790
1791 CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
1792 CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
1793 CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
1794 CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);
1795
1796
1797 -- Protected titles - nonexistent pages that have been protected
1798 CREATE TABLE /*_*/protected_titles (
1799 pt_namespace int NOT NULL,
1800 pt_title varchar(255) binary NOT NULL,
1801 pt_user int unsigned NOT NULL,
1802 pt_reason varbinary(767) default '', -- Deprecated.
1803 pt_reason_id bigint unsigned NOT NULL DEFAULT 0, -- ("DEFAULT 0" is temporary, signaling that pt_reason should be used)
1804 pt_timestamp binary(14) NOT NULL,
1805 pt_expiry varbinary(14) NOT NULL default '',
1806 pt_create_perm varbinary(60) NOT NULL
1807 ) /*$wgDBTableOptions*/;
1808
1809 CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
1810 CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);
1811
1812
1813 -- Name/value pairs indexed by page_id
1814 CREATE TABLE /*_*/page_props (
1815 pp_page int NOT NULL,
1816 pp_propname varbinary(60) NOT NULL,
1817 pp_value blob NOT NULL,
1818 pp_sortkey float DEFAULT NULL
1819 ) /*$wgDBTableOptions*/;
1820
1821 CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
1822 CREATE UNIQUE INDEX /*i*/pp_propname_page ON /*_*/page_props (pp_propname,pp_page);
1823 CREATE UNIQUE INDEX /*i*/pp_propname_sortkey_page ON /*_*/page_props (pp_propname,pp_sortkey,pp_page);
1824
1825 -- A table to log updates, one text key row per update.
1826 CREATE TABLE /*_*/updatelog (
1827 ul_key varchar(255) NOT NULL PRIMARY KEY,
1828 ul_value blob
1829 ) /*$wgDBTableOptions*/;
1830
1831
1832 -- A table to track tags for revisions, logs and recent changes.
1833 CREATE TABLE /*_*/change_tag (
1834 ct_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1835 -- RCID for the change
1836 ct_rc_id int NULL,
1837 -- LOGID for the change
1838 ct_log_id int unsigned NULL,
1839 -- REVID for the change
1840 ct_rev_id int unsigned NULL,
1841 -- Tag applied
1842 ct_tag varchar(255) NOT NULL,
1843 -- Parameters for the tag; used by some extensions
1844 ct_params blob NULL
1845 ) /*$wgDBTableOptions*/;
1846
1847 CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
1848 CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
1849 CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
1850 -- Covering index, so we can pull all the info only out of the index.
1851 CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
1852
1853
1854 -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
1855 -- that only works on MySQL 4.1+
1856 CREATE TABLE /*_*/tag_summary (
1857 ts_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1858 -- RCID for the change
1859 ts_rc_id int NULL,
1860 -- LOGID for the change
1861 ts_log_id int unsigned NULL,
1862 -- REVID for the change
1863 ts_rev_id int unsigned NULL,
1864 -- Comma-separated list of tags
1865 ts_tags blob NOT NULL
1866 ) /*$wgDBTableOptions*/;
1867
1868 CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
1869 CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
1870 CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);
1871
1872
1873 CREATE TABLE /*_*/valid_tag (
1874 vt_tag varchar(255) NOT NULL PRIMARY KEY
1875 ) /*$wgDBTableOptions*/;
1876
1877 -- Table for storing localisation data
1878 CREATE TABLE /*_*/l10n_cache (
1879 -- Language code
1880 lc_lang varbinary(32) NOT NULL,
1881 -- Cache key
1882 lc_key varchar(255) NOT NULL,
1883 -- Value
1884 lc_value mediumblob NOT NULL,
1885 PRIMARY KEY (lc_lang, lc_key)
1886 ) /*$wgDBTableOptions*/;
1887
1888 -- Table caching which local files a module depends on that aren't
1889 -- registered directly, used for fast retrieval of file dependency.
1890 -- Currently only used for tracking images that CSS depends on
1891 CREATE TABLE /*_*/module_deps (
1892 -- Module name
1893 md_module varbinary(255) NOT NULL,
1894 -- Module context vary (includes skin and language; called "md_skin" for legacy reasons)
1895 md_skin varbinary(32) NOT NULL,
1896 -- JSON blob with file dependencies
1897 md_deps mediumblob NOT NULL,
1898 PRIMARY KEY (md_module,md_skin)
1899 ) /*$wgDBTableOptions*/;
1900
1901 -- Holds all the sites known to the wiki.
1902 CREATE TABLE /*_*/sites (
1903 -- Numeric id of the site
1904 site_id INT UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
1905
1906 -- Global identifier for the site, ie 'enwiktionary'
1907 site_global_key varbinary(32) NOT NULL,
1908
1909 -- Type of the site, ie 'mediawiki'
1910 site_type varbinary(32) NOT NULL,
1911
1912 -- Group of the site, ie 'wikipedia'
1913 site_group varbinary(32) NOT NULL,
1914
1915 -- Source of the site data, ie 'local', 'wikidata', 'my-magical-repo'
1916 site_source varbinary(32) NOT NULL,
1917
1918 -- Language code of the sites primary language.
1919 site_language varbinary(32) NOT NULL,
1920
1921 -- Protocol of the site, ie 'http://', 'irc://', '//'
1922 -- This field is an index for lookups and is build from type specific data in site_data.
1923 site_protocol varbinary(32) NOT NULL,
1924
1925 -- Domain of the site in reverse order, ie 'org.mediawiki.www.'
1926 -- This field is an index for lookups and is build from type specific data in site_data.
1927 site_domain VARCHAR(255) NOT NULL,
1928
1929 -- Type dependent site data.
1930 site_data BLOB NOT NULL,
1931
1932 -- If site.tld/path/key:pageTitle should forward users to the page on
1933 -- the actual site, where "key" is the local identifier.
1934 site_forward bool NOT NULL,
1935
1936 -- Type dependent site config.
1937 -- For instance if template transclusion should be allowed if it's a MediaWiki.
1938 site_config BLOB NOT NULL
1939 ) /*$wgDBTableOptions*/;
1940
1941 CREATE UNIQUE INDEX /*i*/sites_global_key ON /*_*/sites (site_global_key);
1942 CREATE INDEX /*i*/sites_type ON /*_*/sites (site_type);
1943 CREATE INDEX /*i*/sites_group ON /*_*/sites (site_group);
1944 CREATE INDEX /*i*/sites_source ON /*_*/sites (site_source);
1945 CREATE INDEX /*i*/sites_language ON /*_*/sites (site_language);
1946 CREATE INDEX /*i*/sites_protocol ON /*_*/sites (site_protocol);
1947 CREATE INDEX /*i*/sites_domain ON /*_*/sites (site_domain);
1948 CREATE INDEX /*i*/sites_forward ON /*_*/sites (site_forward);
1949
1950 -- Links local site identifiers to their corresponding site.
1951 CREATE TABLE /*_*/site_identifiers (
1952 -- Key on site.site_id
1953 si_site INT UNSIGNED NOT NULL,
1954
1955 -- local key type, ie 'interwiki' or 'langlink'
1956 si_type varbinary(32) NOT NULL,
1957
1958 -- local key value, ie 'en' or 'wiktionary'
1959 si_key varbinary(32) NOT NULL
1960 ) /*$wgDBTableOptions*/;
1961
1962 CREATE UNIQUE INDEX /*i*/site_ids_type ON /*_*/site_identifiers (si_type, si_key);
1963 CREATE INDEX /*i*/site_ids_site ON /*_*/site_identifiers (si_site);
1964 CREATE INDEX /*i*/site_ids_key ON /*_*/site_identifiers (si_key);
1965
1966 -- vim: sw=2 sts=2 et