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