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