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