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