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