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