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