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