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