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