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