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