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