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