18b766f3ce378dda9c5dbd7c0bb0d29c0063b1c7
[lhc/web/wiklou.git] / maintenance / mysql5 / tables.sql
1 -- Experimental table definitions for MySQL 4.1 and 5.0 with
2 -- explicit character set support. Not fully tested, may have
3 -- surprises!
4 --
5 -- TODO: Test various fields
6 -- TODO: Anything else need to be moved to VARBINARY and BLOB?
7 -- TODO: UCS-2 better than UTF-8?
8 -- TODO: Find out how to get 4-byte UTF-8 chars into MySQL...
9 -- An alternate UCS-2 that does UTF-16 conversion would work.
10 -- TODO: Work on collation usage
11
12 -- ------------------------------------------------------------
13
14 -- SQL to create the initial tables for the MediaWiki database.
15 -- This is read and executed by the install script; you should
16 -- not have to run it by itself unless doing a manual install.
17
18 --
19 -- General notes:
20 --
21 -- If possible, create tables as InnoDB to benefit from the
22 -- superior resiliency against crashes and ability to read
23 -- during writes (and write during reads!)
24 --
25 -- Only the 'searchindex' table requires MyISAM due to the
26 -- requirement for fulltext index support, which is missing
27 -- from InnoDB.
28 --
29 --
30 -- The MySQL table backend for MediaWiki currently uses
31 -- 14-character CHAR or VARCHAR fields to store timestamps.
32 -- The format is YYYYMMDDHHMMSS, which is derived from the
33 -- text format of MySQL's TIMESTAMP fields.
34 --
35 -- Historically TIMESTAMP fields were used, but abandoned
36 -- in early 2002 after a lot of trouble with the fields
37 -- auto-updating.
38 --
39 -- The Postgres backend uses DATETIME fields for timestamps,
40 -- and we will migrate the MySQL definitions at some point as
41 -- well.
42 --
43 --
44 -- The /*$wgDBprefix*/ comments in this and other files are
45 -- replaced with the defined table prefix by the installer
46 -- and updater scripts. If you are installing or running
47 -- updates manually, you will need to manually insert the
48 -- table prefix if any when running these scripts.
49 --
50
51
52 --
53 -- The user table contains basic account information,
54 -- authentication keys, etc.
55 --
56 -- Some multi-wiki sites may share a single central user table
57 -- between separate wikis using the $wgSharedDB setting.
58 --
59 -- Note that when a external authentication plugin is used,
60 -- user table entries still need to be created to store
61 -- preferences and to key tracking information in the other
62 -- tables.
63 --
64 CREATE TABLE /*$wgDBprefix*/user (
65 user_id int(5) unsigned NOT NULL auto_increment,
66
67 -- Usernames must be unique, must not be in the form of
68 -- an IP address. _Shouldn't_ allow slashes or case
69 -- conflicts. Spaces are allowed, and are _not_ converted
70 -- to underscores like titles. See the User::newFromName() for
71 -- the specific tests that usernames have to pass.
72 user_name varchar(255) binary NOT NULL default '',
73
74 -- Optional 'real name' to be displayed in credit listings
75 user_real_name varchar(255) binary NOT NULL default '',
76
77 -- Password hashes, normally hashed like so:
78 -- MD5(CONCAT(user_id,'-',MD5(plaintext_password))), see
79 -- wfEncryptPassword() in GlobalFunctions.php
80 user_password tinyblob NOT NULL,
81
82 -- When using 'mail me a new password', a random
83 -- password is generated and the hash stored here.
84 -- The previous password is left in place until
85 -- someone actually logs in with the new password,
86 -- at which point the hash is moved to user_password
87 -- and the old password is invalidated.
88 user_newpassword tinyblob NOT NULL,
89
90 -- Timestamp of the last time when a new password was
91 -- sent, for throttling purposes
92 user_newpass_time char(14) binary,
93
94 -- Note: email should be restricted, not public info.
95 -- Same with passwords.
96 user_email tinytext NOT NULL,
97
98 -- Newline-separated list of name=value defining the user
99 -- preferences
100 user_options blob NOT NULL,
101
102 -- This is a timestamp which is updated when a user
103 -- logs in, logs out, changes preferences, or performs
104 -- some other action requiring HTML cache invalidation
105 -- to ensure that the UI is updated.
106 user_touched char(14) binary NOT NULL default '',
107
108 -- A pseudorandomly generated value that is stored in
109 -- a cookie when the "remember password" feature is
110 -- used (previously, a hash of the password was used, but
111 -- this was vulnerable to cookie-stealing attacks)
112 user_token char(32) binary NOT NULL default '',
113
114 -- Initially NULL; when a user's e-mail address has been
115 -- validated by returning with a mailed token, this is
116 -- set to the current timestamp.
117 user_email_authenticated char(14) binary,
118
119 -- Randomly generated token created when the e-mail address
120 -- is set and a confirmation test mail sent.
121 user_email_token char(32) binary,
122
123 -- Expiration date for the user_email_token
124 user_email_token_expires char(14) binary,
125
126 -- Timestamp of account registration.
127 -- Accounts predating this schema addition may contain NULL.
128 user_registration char(14) binary,
129
130 -- Count of edits and edit-like actions.
131 --
132 -- *NOT* intended to be an accurate copy of COUNT(*) WHERE rev_user=user_id
133 -- May contain NULL for old accounts if batch-update scripts haven't been
134 -- run, as well as listing deleted edits and other myriad ways it could be
135 -- out of sync.
136 --
137 -- Meant primarily for heuristic checks to give an impression of whether
138 -- the account has been used much.
139 --
140 user_editcount int,
141
142 PRIMARY KEY user_id (user_id),
143 UNIQUE INDEX user_name (user_name),
144 INDEX (user_email_token)
145
146 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
147
148 --
149 -- User permissions have been broken out to a separate table;
150 -- this allows sites with a shared user table to have different
151 -- permissions assigned to a user in each project.
152 --
153 -- This table replaces the old user_rights field which used a
154 -- comma-separated blob.
155 --
156 CREATE TABLE /*$wgDBprefix*/user_groups (
157 -- Key to user_id
158 ug_user int(5) unsigned NOT NULL default '0',
159
160 -- Group names are short symbolic string keys.
161 -- The set of group names is open-ended, though in practice
162 -- only some predefined ones are likely to be used.
163 --
164 -- At runtime $wgGroupPermissions will associate group keys
165 -- with particular permissions. A user will have the combined
166 -- permissions of any group they're explicitly in, plus
167 -- the implicit '*' and 'user' groups.
168 ug_group char(16) NOT NULL default '',
169
170 PRIMARY KEY (ug_user,ug_group),
171 KEY (ug_group)
172 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
173
174 -- Stores notifications of user talk page changes, for the display
175 -- of the "you have new messages" box
176 CREATE TABLE /*$wgDBprefix*/user_newtalk (
177 -- Key to user.user_id
178 user_id int(5) NOT NULL default '0',
179 -- If the user is an anonymous user hir IP address is stored here
180 -- since the user_id of 0 is ambiguous
181 user_ip varchar(40) NOT NULL default '',
182 INDEX user_id (user_id),
183 INDEX user_ip (user_ip)
184
185 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
186
187
188 --
189 -- Core of the wiki: each page has an entry here which identifies
190 -- it by title and contains some essential metadata.
191 --
192 CREATE TABLE /*$wgDBprefix*/page (
193 -- Unique identifier number. The page_id will be preserved across
194 -- edits and rename operations, but not deletions and recreations.
195 page_id int(8) unsigned NOT NULL auto_increment,
196
197 -- A page name is broken into a namespace and a title.
198 -- The namespace keys are UI-language-independent constants,
199 -- defined in includes/Defines.php
200 page_namespace int NOT NULL,
201
202 -- The rest of the title, as text.
203 -- Spaces are transformed into underscores in title storage.
204 page_title varchar(255) binary NOT NULL,
205
206 -- Comma-separated set of permission keys indicating who
207 -- can move or edit the page.
208 page_restrictions tinyblob NOT NULL,
209
210 -- Number of times this page has been viewed.
211 page_counter bigint(20) unsigned NOT NULL default '0',
212
213 -- 1 indicates the article is a redirect.
214 page_is_redirect tinyint(1) unsigned NOT NULL default '0',
215
216 -- 1 indicates this is a new entry, with only one edit.
217 -- Not all pages with one edit are new pages.
218 page_is_new tinyint(1) unsigned NOT NULL default '0',
219
220 -- Random value between 0 and 1, used for Special:Randompage
221 page_random real unsigned NOT NULL,
222
223 -- This timestamp is updated whenever the page changes in
224 -- a way requiring it to be re-rendered, invalidating caches.
225 -- Aside from editing this includes permission changes,
226 -- creation or deletion of linked pages, and alteration
227 -- of contained templates.
228 page_touched char(14) binary NOT NULL default '',
229
230 -- Handy key to revision.rev_id of the current revision.
231 -- This may be 0 during page creation, but that shouldn't
232 -- happen outside of a transaction... hopefully.
233 page_latest int(8) unsigned NOT NULL,
234
235 -- Uncompressed length in bytes of the page's current source text.
236 page_len int(8) unsigned NOT NULL,
237
238 PRIMARY KEY page_id (page_id),
239 UNIQUE INDEX name_title (page_namespace,page_title),
240
241 -- Special-purpose indexes
242 INDEX (page_random),
243 INDEX (page_len)
244
245 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
246
247 --
248 -- Every edit of a page creates also a revision row.
249 -- This stores metadata about the revision, and a reference
250 -- to the text storage backend.
251 --
252 CREATE TABLE /*$wgDBprefix*/revision (
253 rev_id int(8) unsigned NOT NULL auto_increment,
254
255 -- Key to page_id. This should _never_ be invalid.
256 rev_page int(8) unsigned NOT NULL,
257
258 -- Key to text.old_id, where the actual bulk text is stored.
259 -- It's possible for multiple revisions to use the same text,
260 -- for instance revisions where only metadata is altered
261 -- or a rollback to a previous version.
262 rev_text_id int(8) unsigned NOT NULL,
263
264 -- Text comment summarizing the change.
265 -- This text is shown in the history and other changes lists,
266 -- rendered in a subset of wiki markup by Linker::formatComment()
267 rev_comment tinyblob NOT NULL,
268
269 -- Key to user.user_id of the user who made this edit.
270 -- Stores 0 for anonymous edits and for some mass imports.
271 rev_user int(5) unsigned NOT NULL default '0',
272
273 -- Text username or IP address of the editor.
274 rev_user_text varchar(255) binary NOT NULL default '',
275
276 -- Timestamp
277 rev_timestamp char(14) binary NOT NULL default '',
278
279 -- Records whether the user marked the 'minor edit' checkbox.
280 -- Many automated edits are marked as minor.
281 rev_minor_edit tinyint(1) unsigned NOT NULL default '0',
282
283 -- Not yet used; reserved for future changes to the deletion system.
284 rev_deleted tinyint(1) unsigned NOT NULL default '0',
285
286 -- Length of this revision in bytes
287 rev_len int(8) unsigned,
288
289 -- Key to revision.rev_id
290 -- This field is used to add support for a tree structure (The Adjacency List Model)
291 rev_parent_id int(8) unsigned default NULL,
292
293 PRIMARY KEY rev_page_id (rev_page, rev_id),
294 UNIQUE INDEX rev_id (rev_id),
295 INDEX rev_timestamp (rev_timestamp),
296 INDEX page_timestamp (rev_page,rev_timestamp),
297 INDEX user_timestamp (rev_user,rev_timestamp),
298 INDEX usertext_timestamp (rev_user_text,rev_timestamp)
299
300 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
301
302
303 --
304 -- Holds text of individual page revisions.
305 --
306 -- Field names are a holdover from the 'old' revisions table in
307 -- MediaWiki 1.4 and earlier: an upgrade will transform that
308 -- table into the 'text' table to minimize unnecessary churning
309 -- and downtime. If upgrading, the other fields will be left unused.
310 --
311 CREATE TABLE /*$wgDBprefix*/text (
312 -- Unique text storage key number.
313 -- Note that the 'oldid' parameter used in URLs does *not*
314 -- refer to this number anymore, but to rev_id.
315 --
316 -- revision.rev_text_id is a key to this column
317 old_id int(8) unsigned NOT NULL auto_increment,
318
319 -- Depending on the contents of the old_flags field, the text
320 -- may be convenient plain text, or it may be funkily encoded.
321 old_text mediumblob NOT NULL,
322
323 -- Comma-separated list of flags:
324 -- gzip: text is compressed with PHP's gzdeflate() function.
325 -- utf8: text was stored as UTF-8.
326 -- If $wgLegacyEncoding option is on, rows *without* this flag
327 -- will be converted to UTF-8 transparently at load time.
328 -- object: text field contained a serialized PHP object.
329 -- The object either contains multiple versions compressed
330 -- together to achieve a better compression ratio, or it refers
331 -- to another row where the text can be found.
332 old_flags tinyblob NOT NULL,
333
334 PRIMARY KEY old_id (old_id)
335
336 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
337
338 --
339 -- Holding area for deleted articles, which may be viewed
340 -- or restored by admins through the Special:Undelete interface.
341 -- The fields generally correspond to the page, revision, and text
342 -- fields, with several caveats.
343 --
344 CREATE TABLE /*$wgDBprefix*/archive (
345 ar_namespace int NOT NULL default '0',
346 ar_title varchar(255) binary NOT NULL default '',
347
348 -- Newly deleted pages will not store text in this table,
349 -- but will reference the separately existing text rows.
350 -- This field is retained for backwards compatibility,
351 -- so old archived pages will remain accessible after
352 -- upgrading from 1.4 to 1.5.
353 -- Text may be gzipped or otherwise funky.
354 ar_text mediumblob NOT NULL,
355
356 -- Basic revision stuff...
357 ar_comment tinyblob NOT NULL,
358 ar_user int(5) unsigned NOT NULL default '0',
359 ar_user_text varchar(255) binary NOT NULL,
360 ar_timestamp char(14) binary NOT NULL default '',
361 ar_minor_edit tinyint(1) NOT NULL default '0',
362
363 -- See ar_text note.
364 ar_flags tinyblob NOT NULL,
365
366 -- When revisions are deleted, their unique rev_id is stored
367 -- here so it can be retained after undeletion. This is necessary
368 -- to retain permalinks to given revisions after accidental delete
369 -- cycles or messy operations like history merges.
370 --
371 -- Old entries from 1.4 will be NULL here, and a new rev_id will
372 -- be created on undeletion for those revisions.
373 ar_rev_id int(8) unsigned,
374
375 -- For newly deleted revisions, this is the text.old_id key to the
376 -- actual stored text. To avoid breaking the block-compression scheme
377 -- and otherwise making storage changes harder, the actual text is
378 -- *not* deleted from the text table, merely hidden by removal of the
379 -- page and revision entries.
380 --
381 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
382 -- ar_text and ar_flags fields will be used to create a new text
383 -- row upon undeletion.
384 ar_text_id int(8) unsigned,
385
386 -- rev_deleted for archives
387 ar_deleted tinyint(1) unsigned NOT NULL default '0',
388 -- Length of this revision in bytes
389 rev_len int(8) unsigned,
390
391 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp)
392
393 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
394
395
396 --
397 -- Track page-to-page hyperlinks within the wiki.
398 --
399 CREATE TABLE /*$wgDBprefix*/pagelinks (
400 -- Key to the page_id of the page containing the link.
401 pl_from int(8) unsigned NOT NULL default '0',
402
403 -- Key to page_namespace/page_title of the target page.
404 -- The target page may or may not exist, and due to renames
405 -- and deletions may refer to different page records as time
406 -- goes by.
407 pl_namespace int NOT NULL default '0',
408 pl_title varchar(255) binary NOT NULL default '',
409
410 UNIQUE KEY pl_from (pl_from,pl_namespace,pl_title),
411 KEY (pl_namespace,pl_title,pl_from)
412
413 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
414
415
416 --
417 -- Track template inclusions.
418 --
419 CREATE TABLE /*$wgDBprefix*/templatelinks (
420 -- Key to the page_id of the page containing the link.
421 tl_from int(8) unsigned NOT NULL default '0',
422
423 -- Key to page_namespace/page_title of the target page.
424 -- The target page may or may not exist, and due to renames
425 -- and deletions may refer to different page records as time
426 -- goes by.
427 tl_namespace int NOT NULL default '0',
428 tl_title varchar(255) binary NOT NULL default '',
429
430 UNIQUE KEY tl_from (tl_from,tl_namespace,tl_title),
431 KEY (tl_namespace,tl_title,tl_from)
432
433 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
434
435 --
436 -- Track links to images *used inline*
437 -- We don't distinguish live from broken links here, so
438 -- they do not need to be changed on upload/removal.
439 --
440 CREATE TABLE /*$wgDBprefix*/imagelinks (
441 -- Key to page_id of the page containing the image / media link.
442 il_from int(8) unsigned NOT NULL default '0',
443
444 -- Filename of target image.
445 -- This is also the page_title of the file's description page;
446 -- all such pages are in namespace 6 (NS_IMAGE).
447 il_to varchar(255) binary NOT NULL default '',
448
449 UNIQUE KEY il_from (il_from,il_to),
450 KEY (il_to,il_from)
451
452 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
453
454 --
455 -- Track category inclusions *used inline*
456 -- This tracks a single level of category membership
457 -- (folksonomic tagging, really).
458 --
459 CREATE TABLE /*$wgDBprefix*/categorylinks (
460 -- Key to page_id of the page defined as a category member.
461 cl_from int(8) unsigned NOT NULL default '0',
462
463 -- Name of the category.
464 -- This is also the page_title of the category's description page;
465 -- all such pages are in namespace 14 (NS_CATEGORY).
466 cl_to varchar(255) binary NOT NULL default '',
467
468 -- The title of the linking page, or an optional override
469 -- to determine sort order. Sorting is by binary order, which
470 -- isn't always ideal, but collations seem to be an exciting
471 -- and dangerous new world in MySQL... The sortkey is updated
472 -- if no override exists and cl_from is renamed.
473 --
474 -- For MySQL 4.1+ with charset set to utf8, the sort key *index*
475 -- needs cut to be smaller than 1024 bytes (at 3 bytes per char).
476 -- To sort properly on the shorter key, this field needs to be
477 -- the same shortness.
478 cl_sortkey varchar(86) binary NOT NULL default '',
479
480 -- This isn't really used at present. Provided for an optional
481 -- sorting method by approximate addition time.
482 cl_timestamp timestamp NOT NULL,
483
484 UNIQUE KEY cl_from (cl_from,cl_to),
485
486 -- We always sort within a given category...
487 KEY cl_sortkey (cl_to,cl_sortkey),
488
489 -- Not really used?
490 KEY cl_timestamp (cl_to,cl_timestamp)
491
492 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
493
494 --
495 -- Track links to external URLs
496 --
497 CREATE TABLE /*$wgDBprefix*/externallinks (
498 -- page_id of the referring page
499 el_from int(8) unsigned NOT NULL default '0',
500
501 -- The URL
502 el_to blob NOT NULL,
503
504 -- In the case of HTTP URLs, this is the URL with any username or password
505 -- removed, and with the labels in the hostname reversed and converted to
506 -- lower case. An extra dot is added to allow for matching of either
507 -- example.com or *.example.com in a single scan.
508 -- Example:
509 -- http://user:password@sub.example.com/page.html
510 -- becomes
511 -- http://com.example.sub./page.html
512 -- which allows for fast searching for all pages under example.com with the
513 -- clause:
514 -- WHERE el_index LIKE 'http://com.example.%'
515 el_index blob NOT NULL,
516
517 KEY (el_from, el_to(40)),
518 KEY (el_to(60), el_from),
519 KEY (el_index(60))
520 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
521
522 --
523 -- Track interlanguage links
524 --
525 CREATE TABLE /*$wgDBprefix*/langlinks (
526 -- page_id of the referring page
527 ll_from int(8) unsigned NOT NULL default '0',
528
529 -- Language code of the target
530 ll_lang varchar(10) binary NOT NULL default '',
531
532 -- Title of the target, including namespace
533 ll_title varchar(255) binary NOT NULL default '',
534
535 UNIQUE KEY (ll_from, ll_lang),
536 KEY (ll_lang, ll_title)
537 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
538
539 --
540 -- Contains a single row with some aggregate info
541 -- on the state of the site.
542 --
543 CREATE TABLE /*$wgDBprefix*/site_stats (
544 -- The single row should contain 1 here.
545 ss_row_id int(8) unsigned NOT NULL,
546
547 -- Total number of page views, if hit counters are enabled.
548 ss_total_views bigint(20) unsigned default '0',
549
550 -- Total number of edits performed.
551 ss_total_edits bigint(20) unsigned default '0',
552
553 -- An approximate count of pages matching the following criteria:
554 -- * in namespace 0
555 -- * not a redirect
556 -- * contains the text '[['
557 -- See Article::isCountable() in includes/Article.php
558 ss_good_articles bigint(20) unsigned default '0',
559
560 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
561 ss_total_pages bigint(20) default '-1',
562
563 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
564 ss_users bigint(20) default '-1',
565
566 -- Deprecated, no longer updated as of 1.5
567 ss_admins int(10) default '-1',
568
569 -- Number of images, equivalent to SELECT COUNT(*) FROM image
570 ss_images int(10) default '0',
571
572 UNIQUE KEY ss_row_id (ss_row_id)
573
574 ) ENGINE=InnoDB;
575
576 --
577 -- Stores an ID for every time any article is visited;
578 -- depending on $wgHitcounterUpdateFreq, it is
579 -- periodically cleared and the page_counter column
580 -- in the page table updated for the all articles
581 -- that have been visited.)
582 --
583 CREATE TABLE /*$wgDBprefix*/hitcounter (
584 hc_id int unsigned NOT NULL
585 ) ENGINE=HEAP MAX_ROWS=25000;
586
587
588 --
589 -- The internet is full of jerks, alas. Sometimes it's handy
590 -- to block a vandal or troll account.
591 --
592 CREATE TABLE /*$wgDBprefix*/ipblocks (
593 -- Primary key, introduced for privacy.
594 ipb_id int(8) NOT NULL auto_increment,
595
596 -- Blocked IP address in dotted-quad form or user name.
597 ipb_address tinyblob NOT NULL,
598
599 -- Blocked user ID or 0 for IP blocks.
600 ipb_user int(8) unsigned NOT NULL default '0',
601
602 -- User ID who made the block.
603 ipb_by int(8) unsigned NOT NULL default '0',
604
605 -- Text comment made by blocker.
606 ipb_reason tinyblob NOT NULL,
607
608 -- Creation (or refresh) date in standard YMDHMS form.
609 -- IP blocks expire automatically.
610 ipb_timestamp char(14) binary NOT NULL default '',
611
612 -- Indicates that the IP address was banned because a banned
613 -- user accessed a page through it. If this is 1, ipb_address
614 -- will be hidden, and the block identified by block ID number.
615 ipb_auto bool NOT NULL default 0,
616
617 -- If set to 1, block applies only to logged-out users
618 ipb_anon_only bool NOT NULL default 0,
619
620 -- Block prevents account creation from matching IP addresses
621 ipb_create_account bool NOT NULL default 1,
622
623 -- Block triggers autoblocks
624 ipb_enable_autoblock bool NOT NULL default '1',
625
626 -- Time at which the block will expire.
627 ipb_expiry char(14) binary NOT NULL default '',
628
629 -- Start and end of an address range, in hexadecimal
630 -- Size chosen to allow IPv6
631 ipb_range_start tinyblob NOT NULL,
632 ipb_range_end tinyblob NOT NULL,
633 -- Flag for entries hidden from users and Sysops
634 ipb_deleted bool NOT NULL default 0,
635
636 PRIMARY KEY ipb_id (ipb_id),
637
638 -- Unique index to support "user already blocked" messages
639 -- Any new options which prevent collisions should be included
640 UNIQUE INDEX ipb_address (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only),
641
642 INDEX ipb_user (ipb_user),
643 INDEX ipb_range (ipb_range_start(8), ipb_range_end(8)),
644 INDEX ipb_timestamp (ipb_timestamp),
645 INDEX ipb_expiry (ipb_expiry)
646
647 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
648
649
650 --
651 -- Uploaded images and other files.
652 --
653 CREATE TABLE /*$wgDBprefix*/image (
654 -- Filename.
655 -- This is also the title of the associated description page,
656 -- which will be in namespace 6 (NS_IMAGE).
657 img_name varchar(255) binary NOT NULL default '',
658
659 -- File size in bytes.
660 img_size int(8) unsigned NOT NULL default '0',
661
662 -- For images, size in pixels.
663 img_width int(5) NOT NULL default '0',
664 img_height int(5) NOT NULL default '0',
665
666 -- Extracted EXIF metadata stored as a serialized PHP array.
667 img_metadata mediumblob NOT NULL,
668
669 -- For images, bits per pixel if known.
670 img_bits int(3) NOT NULL default '0',
671
672 -- Media type as defined by the MEDIATYPE_xxx constants
673 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
674
675 -- major part of a MIME media type as defined by IANA
676 -- see http://www.iana.org/assignments/media-types/
677 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
678
679 -- minor part of a MIME media type as defined by IANA
680 -- the minor parts are not required to adher to any standard
681 -- but should be consistent throughout the database
682 -- see http://www.iana.org/assignments/media-types/
683 img_minor_mime varchar(32) NOT NULL default "unknown",
684
685 -- Description field as entered by the uploader.
686 -- This is displayed in image upload history and logs.
687 img_description tinyblob NOT NULL,
688
689 -- user_id and user_name of uploader.
690 img_user int(5) unsigned NOT NULL default '0',
691 img_user_text varchar(255) binary NOT NULL,
692
693 -- Time of the upload.
694 img_timestamp char(14) binary NOT NULL default '',
695
696 PRIMARY KEY img_name (img_name),
697
698 -- Used by Special:Imagelist for sort-by-size
699 INDEX img_size (img_size),
700
701 -- Used by Special:Newimages and Special:Imagelist
702 INDEX img_timestamp (img_timestamp)
703
704 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
705
706 --
707 -- Previous revisions of uploaded files.
708 -- Awkwardly, image rows have to be moved into
709 -- this table at re-upload time.
710 --
711 CREATE TABLE /*$wgDBprefix*/oldimage (
712 -- Base filename: key to image.img_name
713 oi_name varchar(255) binary NOT NULL default '',
714
715 -- Filename of the archived file.
716 -- This is generally a timestamp and '!' prepended to the base name.
717 oi_archive_name varchar(255) binary NOT NULL default '',
718
719 -- Other fields as in image...
720 oi_size int(8) unsigned NOT NULL default 0,
721 oi_width int(5) NOT NULL default 0,
722 oi_height int(5) NOT NULL default 0,
723 oi_bits int(3) NOT NULL default 0,
724 oi_description tinyblob NOT NULL,
725 oi_user int(5) unsigned NOT NULL default '0',
726 oi_user_text varchar(255) binary NOT NULL,
727 oi_timestamp char(14) binary NOT NULL default '',
728
729 INDEX oi_name (oi_name(10))
730
731 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
732
733 --
734 -- Record of deleted file data
735 --
736 CREATE TABLE /*$wgDBprefix*/filearchive (
737 -- Unique row id
738 fa_id int NOT NULL auto_increment,
739
740 -- Original base filename; key to image.img_name, page.page_title, etc
741 fa_name varchar(255) binary NOT NULL default '',
742
743 -- Filename of archived file, if an old revision
744 fa_archive_name varchar(255) binary default '',
745
746 -- Which storage bin (directory tree or object store) the file data
747 -- is stored in. Should be 'deleted' for files that have been deleted;
748 -- any other bin is not yet in use.
749 fa_storage_group varchar(16),
750
751 -- SHA-1 of the file contents plus extension, used as a key for storage.
752 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
753 --
754 -- If NULL, the file was missing at deletion time or has been purged
755 -- from the archival storage.
756 fa_storage_key varchar(64) binary default '',
757
758 -- Deletion information, if this file is deleted.
759 fa_deleted_user int,
760 fa_deleted_timestamp char(14) binary default '',
761 fa_deleted_reason text,
762
763 -- Visibility of deleted revisions, bitfield
764 fa_deleted tinyint(1) unsigned NOT NULL default '0',
765
766 -- Duped fields from image
767 fa_size int(8) unsigned default '0',
768 fa_width int(5) default '0',
769 fa_height int(5) default '0',
770 fa_metadata mediumblob,
771 fa_bits int(3) default '0',
772 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
773 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
774 fa_minor_mime varchar(32) default "unknown",
775 fa_description tinyblob,
776 fa_user int(5) unsigned default '0',
777 fa_user_text varchar(255) binary,
778 fa_timestamp char(14) binary default '',
779
780 PRIMARY KEY (fa_id),
781 INDEX (fa_name, fa_timestamp), -- pick out by image name
782 INDEX (fa_storage_group, fa_storage_key), -- pick out dupe files
783 INDEX (fa_deleted_timestamp), -- sort by deletion time
784 INDEX (fa_deleted_user) -- sort by deleter
785
786 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
787
788 --
789 -- Primarily a summary table for Special:Recentchanges,
790 -- this table contains some additional info on edits from
791 -- the last few days, see Article::editUpdates()
792 --
793 CREATE TABLE /*$wgDBprefix*/recentchanges (
794 rc_id int(8) NOT NULL auto_increment,
795 rc_timestamp varchar(14) binary NOT NULL default '',
796 rc_cur_time varchar(14) binary NOT NULL default '',
797
798 -- As in revision
799 rc_user int(10) unsigned NOT NULL default '0',
800 rc_user_text varchar(255) binary NOT NULL,
801
802 -- When pages are renamed, their RC entries do _not_ change.
803 rc_namespace int NOT NULL default '0',
804 rc_title varchar(255) binary NOT NULL default '',
805
806 -- as in revision...
807 rc_comment varchar(255) binary NOT NULL default '',
808 rc_minor tinyint(3) unsigned NOT NULL default '0',
809
810 -- Edits by user accounts with the 'bot' rights key are
811 -- marked with a 1 here, and will be hidden from the
812 -- default view.
813 rc_bot tinyint(3) unsigned NOT NULL default '0',
814
815 rc_new tinyint(3) unsigned NOT NULL default '0',
816
817 -- Key to page_id (was cur_id prior to 1.5).
818 -- This will keep links working after moves while
819 -- retaining the at-the-time name in the changes list.
820 rc_cur_id int(10) unsigned NOT NULL default '0',
821
822 -- rev_id of the given revision
823 rc_this_oldid int(10) unsigned NOT NULL default '0',
824
825 -- rev_id of the prior revision, for generating diff links.
826 rc_last_oldid int(10) unsigned NOT NULL default '0',
827
828 -- These may no longer be used, with the new move log.
829 rc_type tinyint(3) unsigned NOT NULL default '0',
830 rc_moved_to_ns tinyint(3) unsigned NOT NULL default '0',
831 rc_moved_to_title varchar(255) binary NOT NULL default '',
832
833 -- If the Recent Changes Patrol option is enabled,
834 -- users may mark edits as having been reviewed to
835 -- remove a warning flag on the RC list.
836 -- A value of 1 indicates the page has been reviewed.
837 rc_patrolled tinyint(3) unsigned NOT NULL default '0',
838
839 -- Recorded IP address the edit was made from, if the
840 -- $wgPutIPinRC option is enabled.
841 rc_ip char(15) NOT NULL default '',
842
843 -- Text length in characters before
844 -- and after the edit
845 rc_old_len int(10),
846 rc_new_len int(10),
847
848 -- Visibility of deleted revisions, bitfield
849 rc_deleted tinyint(1) unsigned NOT NULL default '0',
850
851 -- Value corresonding to log_id, specific log entries
852 rc_logid int(10) unsigned NOT NULL default '0',
853 -- Store log type info here, or null
854 rc_log_type varchar(255) binary NULL default NULL,
855 -- Store log action or null
856 rc_log_action varchar(255) binary NULL default NULL,
857 -- Log params
858 rc_params blob NOT NULL default '',
859
860 PRIMARY KEY rc_id (rc_id),
861 INDEX rc_timestamp (rc_timestamp),
862 INDEX rc_namespace_title (rc_namespace, rc_title),
863 INDEX rc_cur_id (rc_cur_id),
864 INDEX new_name_timestamp (rc_new,rc_namespace,rc_timestamp),
865 INDEX rc_ip (rc_ip),
866 INDEX rc_ns_usertext (rc_namespace, rc_user_text),
867 INDEX rc_user_text (rc_user_text, rc_timestamp)
868
869 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
870
871 CREATE TABLE /*$wgDBprefix*/watchlist (
872 -- Key to user.user_id
873 wl_user int(5) unsigned NOT NULL,
874
875 -- Key to page_namespace/page_title
876 -- Note that users may watch pages which do not exist yet,
877 -- or existed in the past but have been deleted.
878 wl_namespace int NOT NULL default '0',
879 wl_title varchar(255) binary NOT NULL default '',
880
881 -- Timestamp when user was last sent a notification e-mail;
882 -- cleared when the user visits the page.
883 wl_notificationtimestamp varchar(14) binary,
884
885 UNIQUE KEY (wl_user, wl_namespace, wl_title),
886 KEY namespace_title (wl_namespace, wl_title)
887
888 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
889
890
891 --
892 -- Used by the math module to keep track
893 -- of previously-rendered items.
894 --
895 CREATE TABLE /*$wgDBprefix*/math (
896 -- Binary MD5 hash of the latex fragment, used as an identifier key.
897 math_inputhash varbinary(16) NOT NULL,
898
899 -- Not sure what this is, exactly...
900 math_outputhash varbinary(16) NOT NULL,
901
902 -- texvc reports how well it thinks the HTML conversion worked;
903 -- if it's a low level the PNG rendering may be preferred.
904 math_html_conservativeness tinyint(1) NOT NULL,
905
906 -- HTML output from texvc, if any
907 math_html text,
908
909 -- MathML output from texvc, if any
910 math_mathml text,
911
912 UNIQUE KEY math_inputhash (math_inputhash)
913
914 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
915
916 --
917 -- When using the default MySQL search backend, page titles
918 -- and text are munged to strip markup, do Unicode case folding,
919 -- and prepare the result for MySQL's fulltext index.
920 --
921 -- This table must be MyISAM; InnoDB does not support the needed
922 -- fulltext index.
923 --
924 CREATE TABLE /*$wgDBprefix*/searchindex (
925 -- Key to page_id
926 si_page int(8) unsigned NOT NULL,
927
928 -- Munged version of title
929 si_title varchar(255) NOT NULL default '',
930
931 -- Munged version of body text
932 si_text mediumtext NOT NULL,
933
934 UNIQUE KEY (si_page),
935 FULLTEXT si_title (si_title),
936 FULLTEXT si_text (si_text)
937
938 ) ENGINE=MyISAM, DEFAULT CHARSET=utf8;
939
940 --
941 -- Recognized interwiki link prefixes
942 --
943 CREATE TABLE /*$wgDBprefix*/interwiki (
944 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
945 iw_prefix char(32) NOT NULL,
946
947 -- The URL of the wiki, with "$1" as a placeholder for an article name.
948 -- Any spaces in the name will be transformed to underscores before
949 -- insertion.
950 iw_url char(127) NOT NULL,
951
952 -- A boolean value indicating whether the wiki is in this project
953 -- (used, for example, to detect redirect loops)
954 iw_local bool NOT NULL,
955
956 -- Boolean value indicating whether interwiki transclusions are allowed.
957 iw_trans tinyint(1) NOT NULL default 0,
958
959 UNIQUE KEY iw_prefix (iw_prefix)
960
961 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
962
963 --
964 -- Used for caching expensive grouped queries
965 --
966 CREATE TABLE /*$wgDBprefix*/querycache (
967 -- A key name, generally the base name of of the special page.
968 qc_type char(32) NOT NULL,
969
970 -- Some sort of stored value. Sizes, counts...
971 qc_value int(5) unsigned NOT NULL default '0',
972
973 -- Target namespace+title
974 qc_namespace int NOT NULL default '0',
975 qc_title char(255) binary NOT NULL default '',
976
977 KEY (qc_type,qc_value)
978
979 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
980
981 --
982 -- For a few generic cache operations if not using Memcached
983 --
984 CREATE TABLE /*$wgDBprefix*/objectcache (
985 keyname char(255) binary NOT NULL default '',
986 value mediumblob,
987 exptime datetime,
988 UNIQUE KEY (keyname),
989 KEY (exptime)
990
991 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
992
993 --
994 -- Cache of interwiki transclusion
995 --
996 CREATE TABLE /*$wgDBprefix*/transcache (
997 tc_url varchar(255) NOT NULL,
998 tc_contents text,
999 tc_time int NOT NULL,
1000 UNIQUE INDEX tc_url_idx (tc_url)
1001 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
1002
1003 CREATE TABLE /*$wgDBprefix*/logging (
1004 -- Symbolic keys for the general log type and the action type
1005 -- within the log. The output format will be controlled by the
1006 -- action field, but only the type controls categorization.
1007 log_type char(10) NOT NULL default '',
1008 log_action char(10) NOT NULL default '',
1009
1010 -- Timestamp. Duh.
1011 log_timestamp char(14) NOT NULL default '19700101000000',
1012
1013 -- The user who performed this action; key to user_id
1014 log_user int unsigned NOT NULL default 0,
1015
1016 -- Key to the page affected. Where a user is the target,
1017 -- this will point to the user page.
1018 log_namespace int NOT NULL default 0,
1019 log_title varchar(255) binary NOT NULL default '',
1020
1021 -- Freeform text. Interpreted as edit history comments.
1022 log_comment varchar(255) NOT NULL default '',
1023
1024 -- LF separated list of miscellaneous parameters
1025 log_params blob NOT NULL,
1026
1027 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1028 log_id int unsigned NOT NULL auto_increment,
1029
1030 -- rev_deleted for logs
1031 log_deleted tinyint(1) unsigned NOT NULL default '0',
1032
1033 KEY type_time (log_type, log_timestamp),
1034 KEY user_time (log_user, log_timestamp),
1035 KEY page_time (log_namespace, log_title, log_timestamp),
1036 KEY times (log_timestamp)
1037
1038 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
1039
1040 CREATE TABLE /*$wgDBprefix*/trackbacks (
1041 tb_id int auto_increment,
1042 tb_page int REFERENCES page(page_id) ON DELETE CASCADE,
1043 tb_title varchar(255) NOT NULL,
1044 tb_url varchar(255) NOT NULL,
1045 tb_ex text,
1046 tb_name varchar(255),
1047
1048 PRIMARY KEY (tb_id),
1049 INDEX (tb_page)
1050 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
1051
1052
1053 -- Jobs performed by parallel apache threads or a command-line daemon
1054 CREATE TABLE /*$wgDBprefix*/job (
1055 job_id int(9) unsigned NOT NULL auto_increment,
1056
1057 -- Command name, currently only refreshLinks is defined
1058 job_cmd varchar(255) NOT NULL default '',
1059
1060 -- Namespace and title to act on
1061 -- Should be 0 and '' if the command does not operate on a title
1062 job_namespace int NOT NULL,
1063 job_title varchar(255) binary NOT NULL,
1064
1065 -- Any other parameters to the command
1066 -- Presently unused, format undefined
1067 job_params blob NOT NULL,
1068
1069 PRIMARY KEY job_id (job_id),
1070 KEY (job_cmd, job_namespace, job_title)
1071 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
1072
1073
1074 -- Details of updates to cached special pages
1075 CREATE TABLE /*$wgDBprefix*/querycache_info (
1076
1077 -- Special page name
1078 -- Corresponds to a qc_type value
1079 qci_type varchar(32) NOT NULL default '',
1080
1081 -- Timestamp of last update
1082 qci_timestamp char(14) NOT NULL default '19700101000000',
1083
1084 UNIQUE KEY ( qci_type )
1085
1086 ) ENGINE=InnoDB;
1087
1088 -- For each redirect, this table contains exactly one row defining its target
1089 CREATE TABLE /*$wgDBprefix*/redirect (
1090 -- Key to the page_id of the redirect page
1091 rd_from int(8) unsigned NOT NULL default '0',
1092
1093 -- Key to page_namespace/page_title of the target page.
1094 -- The target page may or may not exist, and due to renames
1095 -- and deletions may refer to different page records as time
1096 -- goes by.
1097 rd_namespace int NOT NULL default '0',
1098 rd_title varchar(255) binary NOT NULL default '',
1099
1100 PRIMARY KEY rd_from (rd_from),
1101 KEY rd_ns_title (rd_namespace,rd_title,rd_from)
1102 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
1103
1104 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1105 CREATE TABLE /*$wgDBprefix*/querycachetwo (
1106 -- A key name, generally the base name of of the special page.
1107 qcc_type char(32) NOT NULL,
1108
1109 -- Some sort of stored value. Sizes, counts...
1110 qcc_value int(5) unsigned NOT NULL default '0',
1111
1112 -- Target namespace+title
1113 qcc_namespace int NOT NULL default '0',
1114 qcc_title char(255) binary NOT NULL default '',
1115
1116 -- Target namespace+title2
1117 qcc_namespacetwo int NOT NULL default '0',
1118 qcc_titletwo char(255) binary NOT NULL default '',
1119
1120 KEY qcc_type (qcc_type,qcc_value),
1121 KEY qcc_title (qcc_type,qcc_namespace,qcc_title),
1122 KEY qcc_titletwo (qcc_type,qcc_namespacetwo,qcc_titletwo)
1123
1124 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;
1125
1126 --- Used for storing page restrictions (i.e. protection levels)
1127 CREATE TABLE /*$wgDBprefix*/page_restrictions (
1128 -- Page to apply restrictions to (Foreign Key to page).
1129 pr_page int(8) NOT NULL,
1130 -- The protection type (edit, move, etc)
1131 pr_type varchar(255) NOT NULL,
1132 -- The protection level (Sysop, autoconfirmed, etc)
1133 pr_level varchar(255) NOT NULL,
1134 -- Whether or not to cascade the protection down to pages transcluded.
1135 pr_cascade tinyint(4) NOT NULL,
1136 -- Field for future support of per-user restriction.
1137 pr_user int(8) NULL,
1138 -- Field for time-limited protection.
1139 pr_expiry char(14) binary NULL,
1140 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1141 pr_id int unsigned NOT NULL auto_increment,
1142
1143 PRIMARY KEY pr_pagetype (pr_page,pr_type),
1144
1145 KEY pr_page (pr_page),
1146 KEY pr_typelevel (pr_type,pr_level),
1147 KEY pr_level (pr_level),
1148 KEY pr_cascade (pr_cascade)
1149 ) ENGINE=InnoDB, DEFAULT CHARSET=utf8;