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