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