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