tables.sql needs rev_len
[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,
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,
76
77 -- Timestamp of the last time when a new password was
78 -- sent, for throttling purposes
79 user_newpass_time char(14) binary,
80
81 -- Note: email should be restricted, not public info.
82 -- Same with passwords.
83 user_email tinytext NOT NULL,
84
85 -- Newline-separated list of name=value defining the user
86 -- preferences
87 user_options blob NOT NULL,
88
89 -- This is a timestamp which is updated when a user
90 -- logs in, logs out, changes preferences, or performs
91 -- some other action requiring HTML cache invalidation
92 -- to ensure that the UI is updated.
93 user_touched char(14) binary NOT NULL default '',
94
95 -- A pseudorandomly generated value that is stored in
96 -- a cookie when the "remember password" feature is
97 -- used (previously, a hash of the password was used, but
98 -- this was vulnerable to cookie-stealing attacks)
99 user_token char(32) binary NOT NULL default '',
100
101 -- Initially NULL; when a user's e-mail address has been
102 -- validated by returning with a mailed token, this is
103 -- set to the current timestamp.
104 user_email_authenticated char(14) binary,
105
106 -- Randomly generated token created when the e-mail address
107 -- is set and a confirmation test mail sent.
108 user_email_token char(32) binary,
109
110 -- Expiration date for the user_email_token
111 user_email_token_expires char(14) binary,
112
113 -- Timestamp of account registration.
114 -- Accounts predating this schema addition may contain NULL.
115 user_registration char(14) binary,
116
117 -- Count of edits and edit-like actions.
118 --
119 -- *NOT* intended to be an accurate copy of COUNT(*) WHERE rev_user=user_id
120 -- May contain NULL for old accounts if batch-update scripts haven't been
121 -- run, as well as listing deleted edits and other myriad ways it could be
122 -- out of sync.
123 --
124 -- Meant primarily for heuristic checks to give an impression of whether
125 -- the account has been used much.
126 --
127 user_editcount int,
128
129 PRIMARY KEY user_id (user_id),
130 UNIQUE INDEX user_name (user_name),
131 INDEX (user_email_token)
132
133 ) TYPE=InnoDB;
134
135 --
136 -- User permissions have been broken out to a separate table;
137 -- this allows sites with a shared user table to have different
138 -- permissions assigned to a user in each project.
139 --
140 -- This table replaces the old user_rights field which used a
141 -- comma-separated blob.
142 --
143 CREATE TABLE /*$wgDBprefix*/user_groups (
144 -- Key to user_id
145 ug_user int(5) unsigned NOT NULL default '0',
146
147 -- Group names are short symbolic string keys.
148 -- The set of group names is open-ended, though in practice
149 -- only some predefined ones are likely to be used.
150 --
151 -- At runtime $wgGroupPermissions will associate group keys
152 -- with particular permissions. A user will have the combined
153 -- permissions of any group they're explicitly in, plus
154 -- the implicit '*' and 'user' groups.
155 ug_group char(16) NOT NULL default '',
156
157 PRIMARY KEY (ug_user,ug_group),
158 KEY (ug_group)
159 ) TYPE=InnoDB;
160
161 -- Stores notifications of user talk page changes, for the display
162 -- of the "you have new messages" box
163 CREATE TABLE /*$wgDBprefix*/user_newtalk (
164 -- Key to user.user_id
165 user_id int(5) NOT NULL default '0',
166 -- If the user is an anonymous user hir IP address is stored here
167 -- since the user_id of 0 is ambiguous
168 user_ip varchar(40) NOT NULL default '',
169 INDEX user_id (user_id),
170 INDEX user_ip (user_ip)
171
172 ) TYPE=InnoDB;
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,
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;
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,
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 -- Length of this revision in bytes
274 rev_len int(8) unsigned,
275
276 PRIMARY KEY rev_page_id (rev_page, rev_id),
277 UNIQUE INDEX rev_id (rev_id),
278 INDEX rev_timestamp (rev_timestamp),
279 INDEX page_timestamp (rev_page,rev_timestamp),
280 INDEX user_timestamp (rev_user,rev_timestamp),
281 INDEX usertext_timestamp (rev_user_text,rev_timestamp)
282
283 ) TYPE=InnoDB MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
284 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
285
286 --
287 -- Holds text of individual page revisions.
288 --
289 -- Field names are a holdover from the 'old' revisions table in
290 -- MediaWiki 1.4 and earlier: an upgrade will transform that
291 -- table into the 'text' table to minimize unnecessary churning
292 -- and downtime. If upgrading, the other fields will be left unused.
293 --
294 CREATE TABLE /*$wgDBprefix*/text (
295 -- Unique text storage key number.
296 -- Note that the 'oldid' parameter used in URLs does *not*
297 -- refer to this number anymore, but to rev_id.
298 --
299 -- revision.rev_text_id is a key to this column
300 old_id int(8) unsigned NOT NULL auto_increment,
301
302 -- Depending on the contents of the old_flags field, the text
303 -- may be convenient plain text, or it may be funkily encoded.
304 old_text mediumblob NOT NULL,
305
306 -- Comma-separated list of flags:
307 -- gzip: text is compressed with PHP's gzdeflate() function.
308 -- utf8: text was stored as UTF-8.
309 -- If $wgLegacyEncoding option is on, rows *without* this flag
310 -- will be converted to UTF-8 transparently at load time.
311 -- object: text field contained a serialized PHP object.
312 -- The object either contains multiple versions compressed
313 -- together to achieve a better compression ratio, or it refers
314 -- to another row where the text can be found.
315 old_flags tinyblob NOT NULL,
316
317 PRIMARY KEY old_id (old_id)
318
319 ) TYPE=InnoDB MAX_ROWS=10000000 AVG_ROW_LENGTH=10240;
320 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
321
322 --
323 -- Holding area for deleted articles, which may be viewed
324 -- or restored by admins through the Special:Undelete interface.
325 -- The fields generally correspond to the page, revision, and text
326 -- fields, with several caveats.
327 --
328 CREATE TABLE /*$wgDBprefix*/archive (
329 ar_namespace int NOT NULL default '0',
330 ar_title varchar(255) binary NOT NULL default '',
331
332 -- Newly deleted pages will not store text in this table,
333 -- but will reference the separately existing text rows.
334 -- This field is retained for backwards compatibility,
335 -- so old archived pages will remain accessible after
336 -- upgrading from 1.4 to 1.5.
337 -- Text may be gzipped or otherwise funky.
338 ar_text mediumblob NOT NULL,
339
340 -- Basic revision stuff...
341 ar_comment tinyblob NOT NULL,
342 ar_user int(5) unsigned NOT NULL default '0',
343 ar_user_text varchar(255) binary NOT NULL,
344 ar_timestamp char(14) binary NOT NULL default '',
345 ar_minor_edit tinyint(1) NOT NULL default '0',
346
347 -- See ar_text note.
348 ar_flags tinyblob NOT NULL,
349
350 -- When revisions are deleted, their unique rev_id is stored
351 -- here so it can be retained after undeletion. This is necessary
352 -- to retain permalinks to given revisions after accidental delete
353 -- cycles or messy operations like history merges.
354 --
355 -- Old entries from 1.4 will be NULL here, and a new rev_id will
356 -- be created on undeletion for those revisions.
357 ar_rev_id int(8) unsigned,
358
359 -- For newly deleted revisions, this is the text.old_id key to the
360 -- actual stored text. To avoid breaking the block-compression scheme
361 -- and otherwise making storage changes harder, the actual text is
362 -- *not* deleted from the text table, merely hidden by removal of the
363 -- page and revision entries.
364 --
365 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
366 -- ar_text and ar_flags fields will be used to create a new text
367 -- row upon undeletion.
368 ar_text_id int(8) unsigned,
369
370 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp)
371
372 ) TYPE=InnoDB;
373
374
375 --
376 -- Track page-to-page hyperlinks within the wiki.
377 --
378 CREATE TABLE /*$wgDBprefix*/pagelinks (
379 -- Key to the page_id of the page containing the link.
380 pl_from int(8) unsigned NOT NULL default '0',
381
382 -- Key to page_namespace/page_title of the target page.
383 -- The target page may or may not exist, and due to renames
384 -- and deletions may refer to different page records as time
385 -- goes by.
386 pl_namespace int NOT NULL default '0',
387 pl_title varchar(255) binary NOT NULL default '',
388
389 UNIQUE KEY pl_from (pl_from,pl_namespace,pl_title),
390 KEY (pl_namespace,pl_title,pl_from)
391
392 ) TYPE=InnoDB;
393
394
395 --
396 -- Track template inclusions.
397 --
398 CREATE TABLE /*$wgDBprefix*/templatelinks (
399 -- Key to the page_id of the page containing the link.
400 tl_from int(8) unsigned NOT NULL default '0',
401
402 -- Key to page_namespace/page_title of the target page.
403 -- The target page may or may not exist, and due to renames
404 -- and deletions may refer to different page records as time
405 -- goes by.
406 tl_namespace int NOT NULL default '0',
407 tl_title varchar(255) binary NOT NULL default '',
408
409 UNIQUE KEY tl_from (tl_from,tl_namespace,tl_title),
410 KEY (tl_namespace,tl_title,tl_from)
411
412 ) TYPE=InnoDB;
413
414 --
415 -- Track links to images *used inline*
416 -- We don't distinguish live from broken links here, so
417 -- they do not need to be changed on upload/removal.
418 --
419 CREATE TABLE /*$wgDBprefix*/imagelinks (
420 -- Key to page_id of the page containing the image / media link.
421 il_from int(8) unsigned NOT NULL default '0',
422
423 -- Filename of target image.
424 -- This is also the page_title of the file's description page;
425 -- all such pages are in namespace 6 (NS_IMAGE).
426 il_to varchar(255) binary NOT NULL default '',
427
428 UNIQUE KEY il_from (il_from,il_to),
429 KEY (il_to,il_from)
430
431 ) TYPE=InnoDB;
432
433 --
434 -- Track category inclusions *used inline*
435 -- This tracks a single level of category membership
436 -- (folksonomic tagging, really).
437 --
438 CREATE TABLE /*$wgDBprefix*/categorylinks (
439 -- Key to page_id of the page defined as a category member.
440 cl_from int(8) unsigned NOT NULL default '0',
441
442 -- Name of the category.
443 -- This is also the page_title of the category's description page;
444 -- all such pages are in namespace 14 (NS_CATEGORY).
445 cl_to varchar(255) binary NOT NULL default '',
446
447 -- The title of the linking page, or an optional override
448 -- to determine sort order. Sorting is by binary order, which
449 -- isn't always ideal, but collations seem to be an exciting
450 -- and dangerous new world in MySQL... The sortkey is updated
451 -- if no override exists and cl_from is renamed.
452 --
453 -- For MySQL 4.1+ with charset set to utf8, the sort key *index*
454 -- needs cut to be smaller than 1024 bytes (at 3 bytes per char).
455 -- To sort properly on the shorter key, this field needs to be
456 -- the same shortness.
457 cl_sortkey varchar(86) binary NOT NULL default '',
458
459 -- This isn't really used at present. Provided for an optional
460 -- sorting method by approximate addition time.
461 cl_timestamp timestamp NOT NULL,
462
463 UNIQUE KEY cl_from (cl_from,cl_to),
464
465 -- We always sort within a given category...
466 KEY cl_sortkey (cl_to,cl_sortkey),
467
468 -- Not really used?
469 KEY cl_timestamp (cl_to,cl_timestamp)
470
471 ) TYPE=InnoDB;
472
473 --
474 -- Track links to external URLs
475 --
476 CREATE TABLE /*$wgDBprefix*/externallinks (
477 -- page_id of the referring page
478 el_from int(8) unsigned NOT NULL default '0',
479
480 -- The URL
481 el_to blob NOT NULL,
482
483 -- In the case of HTTP URLs, this is the URL with any username or password
484 -- removed, and with the labels in the hostname reversed and converted to
485 -- lower case. An extra dot is added to allow for matching of either
486 -- example.com or *.example.com in a single scan.
487 -- Example:
488 -- http://user:password@sub.example.com/page.html
489 -- becomes
490 -- http://com.example.sub./page.html
491 -- which allows for fast searching for all pages under example.com with the
492 -- clause:
493 -- WHERE el_index LIKE 'http://com.example.%'
494 el_index blob NOT NULL,
495
496 KEY (el_from, el_to(40)),
497 KEY (el_to(60), el_from),
498 KEY (el_index(60))
499 ) TYPE=InnoDB;
500
501 --
502 -- Track interlanguage links
503 --
504 CREATE TABLE /*$wgDBprefix*/langlinks (
505 -- page_id of the referring page
506 ll_from int(8) unsigned NOT NULL default '0',
507
508 -- Language code of the target
509 ll_lang varchar(10) binary NOT NULL default '',
510
511 -- Title of the target, including namespace
512 ll_title varchar(255) binary NOT NULL default '',
513
514 UNIQUE KEY (ll_from, ll_lang),
515 KEY (ll_lang, ll_title)
516 ) TYPE=InnoDB;
517
518 --
519 -- Contains a single row with some aggregate info
520 -- on the state of the site.
521 --
522 CREATE TABLE /*$wgDBprefix*/site_stats (
523 -- The single row should contain 1 here.
524 ss_row_id int(8) unsigned NOT NULL,
525
526 -- Total number of page views, if hit counters are enabled.
527 ss_total_views bigint(20) unsigned default '0',
528
529 -- Total number of edits performed.
530 ss_total_edits bigint(20) unsigned default '0',
531
532 -- An approximate count of pages matching the following criteria:
533 -- * in namespace 0
534 -- * not a redirect
535 -- * contains the text '[['
536 -- See Article::isCountable() in includes/Article.php
537 ss_good_articles bigint(20) unsigned default '0',
538
539 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
540 ss_total_pages bigint(20) default '-1',
541
542 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
543 ss_users bigint(20) default '-1',
544
545 -- Deprecated, no longer updated as of 1.5
546 ss_admins int(10) default '-1',
547
548 -- Number of images, equivalent to SELECT COUNT(*) FROM image
549 ss_images int(10) default '0',
550
551 UNIQUE KEY ss_row_id (ss_row_id)
552
553 ) TYPE=InnoDB;
554
555 --
556 -- Stores an ID for every time any article is visited;
557 -- depending on $wgHitcounterUpdateFreq, it is
558 -- periodically cleared and the page_counter column
559 -- in the page table updated for the all articles
560 -- that have been visited.)
561 --
562 CREATE TABLE /*$wgDBprefix*/hitcounter (
563 hc_id int unsigned NOT NULL
564 ) TYPE=HEAP MAX_ROWS=25000;
565
566
567 --
568 -- The internet is full of jerks, alas. Sometimes it's handy
569 -- to block a vandal or troll account.
570 --
571 CREATE TABLE /*$wgDBprefix*/ipblocks (
572 -- Primary key, introduced for privacy.
573 ipb_id int(8) NOT NULL auto_increment,
574
575 -- Blocked IP address in dotted-quad form or user name.
576 ipb_address tinyblob NOT NULL,
577
578 -- Blocked user ID or 0 for IP blocks.
579 ipb_user int(8) unsigned NOT NULL default '0',
580
581 -- User ID who made the block.
582 ipb_by int(8) unsigned NOT NULL default '0',
583
584 -- Text comment made by blocker.
585 ipb_reason tinyblob NOT NULL,
586
587 -- Creation (or refresh) date in standard YMDHMS form.
588 -- IP blocks expire automatically.
589 ipb_timestamp char(14) binary NOT NULL default '',
590
591 -- Indicates that the IP address was banned because a banned
592 -- user accessed a page through it. If this is 1, ipb_address
593 -- will be hidden, and the block identified by block ID number.
594 ipb_auto bool NOT NULL default 0,
595
596 -- If set to 1, block applies only to logged-out users
597 ipb_anon_only bool NOT NULL default 0,
598
599 -- Block prevents account creation from matching IP addresses
600 ipb_create_account bool NOT NULL default 1,
601
602 -- Block triggers autoblocks
603 ipb_enable_autoblock bool NOT NULL default '1',
604
605 -- Time at which the block will expire.
606 ipb_expiry char(14) binary NOT NULL default '',
607
608 -- Start and end of an address range, in hexadecimal
609 -- Size chosen to allow IPv6
610 ipb_range_start tinyblob NOT NULL,
611 ipb_range_end tinyblob NOT NULL,
612
613 PRIMARY KEY ipb_id (ipb_id),
614
615 -- Unique index to support "user already blocked" messages
616 -- Any new options which prevent collisions should be included
617 UNIQUE INDEX ipb_address (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only),
618
619 INDEX ipb_user (ipb_user),
620 INDEX ipb_range (ipb_range_start(8), ipb_range_end(8)),
621 INDEX ipb_timestamp (ipb_timestamp),
622 INDEX ipb_expiry (ipb_expiry)
623
624 ) TYPE=InnoDB;
625
626
627 --
628 -- Uploaded images and other files.
629 --
630 CREATE TABLE /*$wgDBprefix*/image (
631 -- Filename.
632 -- This is also the title of the associated description page,
633 -- which will be in namespace 6 (NS_IMAGE).
634 img_name varchar(255) binary NOT NULL default '',
635
636 -- File size in bytes.
637 img_size int(8) unsigned NOT NULL default '0',
638
639 -- For images, size in pixels.
640 img_width int(5) NOT NULL default '0',
641 img_height int(5) NOT NULL default '0',
642
643 -- Extracted EXIF metadata stored as a serialized PHP array.
644 img_metadata mediumblob NOT NULL,
645
646 -- For images, bits per pixel if known.
647 img_bits int(3) NOT NULL default '0',
648
649 -- Media type as defined by the MEDIATYPE_xxx constants
650 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
651
652 -- major part of a MIME media type as defined by IANA
653 -- see http://www.iana.org/assignments/media-types/
654 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
655
656 -- minor part of a MIME media type as defined by IANA
657 -- the minor parts are not required to adher to any standard
658 -- but should be consistent throughout the database
659 -- see http://www.iana.org/assignments/media-types/
660 img_minor_mime varchar(32) NOT NULL default "unknown",
661
662 -- Description field as entered by the uploader.
663 -- This is displayed in image upload history and logs.
664 img_description tinyblob NOT NULL,
665
666 -- user_id and user_name of uploader.
667 img_user int(5) unsigned NOT NULL default '0',
668 img_user_text varchar(255) binary NOT NULL,
669
670 -- Time of the upload.
671 img_timestamp char(14) binary NOT NULL default '',
672
673 PRIMARY KEY img_name (img_name),
674
675 -- Used by Special:Imagelist for sort-by-size
676 INDEX img_size (img_size),
677
678 -- Used by Special:Newimages and Special:Imagelist
679 INDEX img_timestamp (img_timestamp)
680
681 ) TYPE=InnoDB;
682
683 --
684 -- Previous revisions of uploaded files.
685 -- Awkwardly, image rows have to be moved into
686 -- this table at re-upload time.
687 --
688 CREATE TABLE /*$wgDBprefix*/oldimage (
689 -- Base filename: key to image.img_name
690 oi_name varchar(255) binary NOT NULL default '',
691
692 -- Filename of the archived file.
693 -- This is generally a timestamp and '!' prepended to the base name.
694 oi_archive_name varchar(255) binary NOT NULL default '',
695
696 -- Other fields as in image...
697 oi_size int(8) unsigned NOT NULL default 0,
698 oi_width int(5) NOT NULL default 0,
699 oi_height int(5) NOT NULL default 0,
700 oi_bits int(3) NOT NULL default 0,
701 oi_description tinyblob NOT NULL,
702 oi_user int(5) unsigned NOT NULL default '0',
703 oi_user_text varchar(255) binary NOT NULL,
704 oi_timestamp char(14) binary NOT NULL default '',
705
706 INDEX oi_name (oi_name(10))
707
708 ) TYPE=InnoDB;
709
710 --
711 -- Record of deleted file data
712 --
713 CREATE TABLE /*$wgDBprefix*/filearchive (
714 -- Unique row id
715 fa_id int NOT NULL auto_increment,
716
717 -- Original base filename; key to image.img_name, page.page_title, etc
718 fa_name varchar(255) binary NOT NULL default '',
719
720 -- Filename of archived file, if an old revision
721 fa_archive_name varchar(255) binary default '',
722
723 -- Which storage bin (directory tree or object store) the file data
724 -- is stored in. Should be 'deleted' for files that have been deleted;
725 -- any other bin is not yet in use.
726 fa_storage_group varchar(16),
727
728 -- SHA-1 of the file contents plus extension, used as a key for storage.
729 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
730 --
731 -- If NULL, the file was missing at deletion time or has been purged
732 -- from the archival storage.
733 fa_storage_key varchar(64) binary default '',
734
735 -- Deletion information, if this file is deleted.
736 fa_deleted_user int,
737 fa_deleted_timestamp char(14) binary default '',
738 fa_deleted_reason text,
739
740 -- Duped fields from image
741 fa_size int(8) unsigned default '0',
742 fa_width int(5) default '0',
743 fa_height int(5) default '0',
744 fa_metadata mediumblob,
745 fa_bits int(3) default '0',
746 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
747 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
748 fa_minor_mime varchar(32) default "unknown",
749 fa_description tinyblob,
750 fa_user int(5) unsigned default '0',
751 fa_user_text varchar(255) binary,
752 fa_timestamp char(14) binary default '',
753
754 PRIMARY KEY (fa_id),
755 INDEX (fa_name, fa_timestamp), -- pick out by image name
756 INDEX (fa_storage_group, fa_storage_key), -- pick out dupe files
757 INDEX (fa_deleted_timestamp), -- sort by deletion time
758 INDEX (fa_deleted_user) -- sort by deleter
759
760 ) TYPE=InnoDB;
761
762 --
763 -- Primarily a summary table for Special:Recentchanges,
764 -- this table contains some additional info on edits from
765 -- the last few days, see Article::editUpdates()
766 --
767 CREATE TABLE /*$wgDBprefix*/recentchanges (
768 rc_id int(8) NOT NULL auto_increment,
769 rc_timestamp varchar(14) binary NOT NULL default '',
770 rc_cur_time varchar(14) binary NOT NULL default '',
771
772 -- As in revision
773 rc_user int(10) unsigned NOT NULL default '0',
774 rc_user_text varchar(255) binary NOT NULL,
775
776 -- When pages are renamed, their RC entries do _not_ change.
777 rc_namespace int NOT NULL default '0',
778 rc_title varchar(255) binary NOT NULL default '',
779
780 -- as in revision...
781 rc_comment varchar(255) binary NOT NULL default '',
782 rc_minor tinyint(3) unsigned NOT NULL default '0',
783
784 -- Edits by user accounts with the 'bot' rights key are
785 -- marked with a 1 here, and will be hidden from the
786 -- default view.
787 rc_bot tinyint(3) unsigned NOT NULL default '0',
788
789 rc_new tinyint(3) unsigned NOT NULL default '0',
790
791 -- Key to page_id (was cur_id prior to 1.5).
792 -- This will keep links working after moves while
793 -- retaining the at-the-time name in the changes list.
794 rc_cur_id int(10) unsigned NOT NULL default '0',
795
796 -- rev_id of the given revision
797 rc_this_oldid int(10) unsigned NOT NULL default '0',
798
799 -- rev_id of the prior revision, for generating diff links.
800 rc_last_oldid int(10) unsigned NOT NULL default '0',
801
802 -- These may no longer be used, with the new move log.
803 rc_type tinyint(3) unsigned NOT NULL default '0',
804 rc_moved_to_ns tinyint(3) unsigned NOT NULL default '0',
805 rc_moved_to_title varchar(255) binary NOT NULL default '',
806
807 -- If the Recent Changes Patrol option is enabled,
808 -- users may mark edits as having been reviewed to
809 -- remove a warning flag on the RC list.
810 -- A value of 1 indicates the page has been reviewed.
811 rc_patrolled tinyint(3) unsigned NOT NULL default '0',
812
813 -- Recorded IP address the edit was made from, if the
814 -- $wgPutIPinRC option is enabled.
815 rc_ip char(15) NOT NULL default '',
816
817 -- Text length in characters before
818 -- and after the edit
819 rc_old_len int(10),
820 rc_new_len int(10),
821
822 PRIMARY KEY rc_id (rc_id),
823 INDEX rc_timestamp (rc_timestamp),
824 INDEX rc_namespace_title (rc_namespace, rc_title),
825 INDEX rc_cur_id (rc_cur_id),
826 INDEX new_name_timestamp (rc_new,rc_namespace,rc_timestamp),
827 INDEX rc_ip (rc_ip),
828 INDEX rc_ns_usertext (rc_namespace, rc_user_text),
829 INDEX rc_user_text (rc_user_text, rc_timestamp)
830
831 ) TYPE=InnoDB;
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 ) TYPE=InnoDB;
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 varchar(16) NOT NULL,
860
861 -- Not sure what this is, exactly...
862 math_outputhash varchar(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 ) TYPE=InnoDB;
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 ) TYPE=MyISAM;
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 ) TYPE=InnoDB;
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 ) TYPE=InnoDB;
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 ) TYPE=InnoDB;
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 ) TYPE=InnoDB;
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 -- Log ID, for referring to this specific log entry, probably for deletion and such.
990 log_id int unsigned not null auto_increment,
991
992 PRIMARY KEY log_id (log_id),
993 KEY type_time (log_type, log_timestamp),
994 KEY user_time (log_user, log_timestamp),
995 KEY page_time (log_namespace, log_title, log_timestamp),
996 KEY times (log_timestamp)
997
998 ) TYPE=InnoDB;
999
1000 CREATE TABLE /*$wgDBprefix*/trackbacks (
1001 tb_id int auto_increment,
1002 tb_page int REFERENCES page(page_id) ON DELETE CASCADE,
1003 tb_title varchar(255) NOT NULL,
1004 tb_url varchar(255) NOT NULL,
1005 tb_ex text,
1006 tb_name varchar(255),
1007
1008 PRIMARY KEY (tb_id),
1009 INDEX (tb_page)
1010 ) TYPE=InnoDB;
1011
1012
1013 -- Jobs performed by parallel apache threads or a command-line daemon
1014 CREATE TABLE /*$wgDBprefix*/job (
1015 job_id int(9) unsigned NOT NULL auto_increment,
1016
1017 -- Command name, currently only refreshLinks is defined
1018 job_cmd varchar(255) NOT NULL default '',
1019
1020 -- Namespace and title to act on
1021 -- Should be 0 and '' if the command does not operate on a title
1022 job_namespace int NOT NULL,
1023 job_title varchar(255) binary NOT NULL,
1024
1025 -- Any other parameters to the command
1026 -- Presently unused, format undefined
1027 job_params blob NOT NULL,
1028
1029 PRIMARY KEY job_id (job_id),
1030 KEY (job_cmd, job_namespace, job_title)
1031 ) TYPE=InnoDB;
1032
1033
1034 -- Details of updates to cached special pages
1035 CREATE TABLE /*$wgDBprefix*/querycache_info (
1036
1037 -- Special page name
1038 -- Corresponds to a qc_type value
1039 qci_type varchar(32) NOT NULL default '',
1040
1041 -- Timestamp of last update
1042 qci_timestamp char(14) NOT NULL default '19700101000000',
1043
1044 UNIQUE KEY ( qci_type )
1045
1046 ) TYPE=InnoDB;
1047
1048 -- For each redirect, this table contains exactly one row defining its target
1049 CREATE TABLE /*$wgDBprefix*/redirect (
1050 -- Key to the page_id of the redirect page
1051 rd_from int(8) unsigned NOT NULL default '0',
1052
1053 -- Key to page_namespace/page_title of the target page.
1054 -- The target page may or may not exist, and due to renames
1055 -- and deletions may refer to different page records as time
1056 -- goes by.
1057 rd_namespace int NOT NULL default '0',
1058 rd_title varchar(255) binary NOT NULL default '',
1059
1060 PRIMARY KEY rd_from (rd_from),
1061 KEY rd_ns_title (rd_namespace,rd_title,rd_from)
1062 ) TYPE=InnoDB;
1063
1064 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1065 CREATE TABLE /*$wgDBprefix*/querycachetwo (
1066 -- A key name, generally the base name of of the special page.
1067 qcc_type char(32) NOT NULL,
1068
1069 -- Some sort of stored value. Sizes, counts...
1070 qcc_value int(5) unsigned NOT NULL default '0',
1071
1072 -- Target namespace+title
1073 qcc_namespace int NOT NULL default '0',
1074 qcc_title char(255) binary NOT NULL default '',
1075
1076 -- Target namespace+title2
1077 qcc_namespacetwo int NOT NULL default '0',
1078 qcc_titletwo char(255) binary NOT NULL default '',
1079
1080 KEY qcc_type (qcc_type,qcc_value),
1081 KEY qcc_title (qcc_type,qcc_namespace,qcc_title),
1082 KEY qcc_titletwo (qcc_type,qcc_namespacetwo,qcc_titletwo)
1083
1084 ) TYPE=InnoDB;
1085
1086 --- Used for storing page restrictions (i.e. protection levels)
1087 CREATE TABLE /*$wgDBprefix*/page_restrictions (
1088 -- Page to apply restrictions to (Foreign Key to page).
1089 pr_page int(8) NOT NULL,
1090 -- The protection type (edit, move, etc)
1091 pr_type varchar(255) NOT NULL,
1092 -- The protection level (Sysop, autoconfirmed, etc)
1093 pr_level varchar(255) NOT NULL,
1094 -- Whether or not to cascade the protection down to pages transcluded.
1095 pr_cascade tinyint(4) NOT NULL,
1096 -- Field for future support of per-user restriction.
1097 pr_user int(8) NULL,
1098 -- Field for time-limited protection.
1099 pr_expiry char(14) binary NULL,
1100 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1101 pr_id int unsigned not null auto_increment,
1102
1103 PRIMARY KEY pr_pagetype (pr_page,pr_type),
1104
1105 UNIQUE KEY pr_id (pr_id),
1106 KEY pr_page (pr_page),
1107 KEY pr_typelevel (pr_type,pr_level),
1108 KEY pr_level (pr_level),
1109 KEY pr_cascade (pr_cascade)
1110 ) TYPE=InnoDB;
1111
1112 -- vim: sw=2 sts=2 et