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