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