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