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