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