8dc09d267aa9c0427fec1afc7e5713d38e015aed
[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 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 MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
281 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
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,
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,
313
314 PRIMARY KEY old_id (old_id)
315
316 ) TYPE=InnoDB MAX_ROWS=10000000 AVG_ROW_LENGTH=10240;
317 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
318
319 --
320 -- Holding area for deleted articles, which may be viewed
321 -- or restored by admins through the Special:Undelete interface.
322 -- The fields generally correspond to the page, revision, and text
323 -- fields, with several caveats.
324 --
325 CREATE TABLE /*$wgDBprefix*/archive (
326 ar_namespace int NOT NULL default '0',
327 ar_title varchar(255) binary NOT NULL default '',
328
329 -- Newly deleted pages will not store text in this table,
330 -- but will reference the separately existing text rows.
331 -- This field is retained for backwards compatibility,
332 -- so old archived pages will remain accessible after
333 -- upgrading from 1.4 to 1.5.
334 -- Text may be gzipped or otherwise funky.
335 ar_text mediumblob NOT NULL,
336
337 -- Basic revision stuff...
338 ar_comment tinyblob NOT NULL,
339 ar_user int(5) unsigned NOT NULL default '0',
340 ar_user_text varchar(255) binary NOT NULL,
341 ar_timestamp char(14) binary NOT NULL default '',
342 ar_minor_edit tinyint(1) NOT NULL default '0',
343
344 -- See ar_text note.
345 ar_flags tinyblob NOT NULL,
346
347 -- When revisions are deleted, their unique rev_id is stored
348 -- here so it can be retained after undeletion. This is necessary
349 -- to retain permalinks to given revisions after accidental delete
350 -- cycles or messy operations like history merges.
351 --
352 -- Old entries from 1.4 will be NULL here, and a new rev_id will
353 -- be created on undeletion for those revisions.
354 ar_rev_id int(8) unsigned,
355
356 -- For newly deleted revisions, this is the text.old_id key to the
357 -- actual stored text. To avoid breaking the block-compression scheme
358 -- and otherwise making storage changes harder, the actual text is
359 -- *not* deleted from the text table, merely hidden by removal of the
360 -- page and revision entries.
361 --
362 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
363 -- ar_text and ar_flags fields will be used to create a new text
364 -- row upon undeletion.
365 ar_text_id int(8) unsigned,
366
367 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp)
368
369 ) TYPE=InnoDB;
370
371
372 --
373 -- Track page-to-page hyperlinks within the wiki.
374 --
375 CREATE TABLE /*$wgDBprefix*/pagelinks (
376 -- Key to the page_id of the page containing the link.
377 pl_from int(8) unsigned NOT NULL default '0',
378
379 -- Key to page_namespace/page_title of the target page.
380 -- The target page may or may not exist, and due to renames
381 -- and deletions may refer to different page records as time
382 -- goes by.
383 pl_namespace int NOT NULL default '0',
384 pl_title varchar(255) binary NOT NULL default '',
385
386 UNIQUE KEY pl_from (pl_from,pl_namespace,pl_title),
387 KEY (pl_namespace,pl_title,pl_from)
388
389 ) TYPE=InnoDB;
390
391
392 --
393 -- Track template inclusions.
394 --
395 CREATE TABLE /*$wgDBprefix*/templatelinks (
396 -- Key to the page_id of the page containing the link.
397 tl_from int(8) unsigned NOT NULL default '0',
398
399 -- Key to page_namespace/page_title of the target page.
400 -- The target page may or may not exist, and due to renames
401 -- and deletions may refer to different page records as time
402 -- goes by.
403 tl_namespace int NOT NULL default '0',
404 tl_title varchar(255) binary NOT NULL default '',
405
406 UNIQUE KEY tl_from (tl_from,tl_namespace,tl_title),
407 KEY (tl_namespace,tl_title,tl_from)
408
409 ) TYPE=InnoDB;
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,il_from)
427
428 ) TYPE=InnoDB;
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... The sortkey is updated
448 -- if no override exists and cl_from is renamed.
449 --
450 -- For MySQL 4.1+ with charset set to utf8, the sort key *index*
451 -- needs cut to be smaller than 1024 bytes (at 3 bytes per char).
452 -- To sort properly on the shorter key, this field needs to be
453 -- the same shortness.
454 cl_sortkey varchar(86) binary NOT NULL default '',
455
456 -- This isn't really used at present. Provided for an optional
457 -- sorting method by approximate addition time.
458 cl_timestamp timestamp NOT NULL,
459
460 UNIQUE KEY cl_from (cl_from,cl_to),
461
462 -- We always sort within a given category...
463 KEY cl_sortkey (cl_to,cl_sortkey),
464
465 -- Not really used?
466 KEY cl_timestamp (cl_to,cl_timestamp)
467
468 ) TYPE=InnoDB;
469
470 --
471 -- Track links to external URLs
472 --
473 CREATE TABLE /*$wgDBprefix*/externallinks (
474 -- page_id of the referring page
475 el_from int(8) unsigned NOT NULL default '0',
476
477 -- The URL
478 el_to blob NOT NULL,
479
480 -- In the case of HTTP URLs, this is the URL with any username or password
481 -- removed, and with the labels in the hostname reversed and converted to
482 -- lower case. An extra dot is added to allow for matching of either
483 -- example.com or *.example.com in a single scan.
484 -- Example:
485 -- http://user:password@sub.example.com/page.html
486 -- becomes
487 -- http://com.example.sub./page.html
488 -- which allows for fast searching for all pages under example.com with the
489 -- clause:
490 -- WHERE el_index LIKE 'http://com.example.%'
491 el_index blob NOT NULL,
492
493 KEY (el_from, el_to(40)),
494 KEY (el_to(60), el_from),
495 KEY (el_index(60))
496 ) TYPE=InnoDB;
497
498 --
499 -- Track interlanguage links
500 --
501 CREATE TABLE /*$wgDBprefix*/langlinks (
502 -- page_id of the referring page
503 ll_from int(8) unsigned NOT NULL default '0',
504
505 -- Language code of the target
506 ll_lang varchar(10) binary NOT NULL default '',
507
508 -- Title of the target, including namespace
509 ll_title varchar(255) binary NOT NULL default '',
510
511 UNIQUE KEY (ll_from, ll_lang),
512 KEY (ll_lang, ll_title)
513 ) TYPE=InnoDB;
514
515 --
516 -- Contains a single row with some aggregate info
517 -- on the state of the site.
518 --
519 CREATE TABLE /*$wgDBprefix*/site_stats (
520 -- The single row should contain 1 here.
521 ss_row_id int(8) unsigned NOT NULL,
522
523 -- Total number of page views, if hit counters are enabled.
524 ss_total_views bigint(20) unsigned default '0',
525
526 -- Total number of edits performed.
527 ss_total_edits bigint(20) unsigned default '0',
528
529 -- An approximate count of pages matching the following criteria:
530 -- * in namespace 0
531 -- * not a redirect
532 -- * contains the text '[['
533 -- See Article::isCountable() in includes/Article.php
534 ss_good_articles bigint(20) unsigned default '0',
535
536 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
537 ss_total_pages bigint(20) default '-1',
538
539 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
540 ss_users bigint(20) default '-1',
541
542 -- Deprecated, no longer updated as of 1.5
543 ss_admins int(10) default '-1',
544
545 -- Number of images, equivalent to SELECT COUNT(*) FROM image
546 ss_images int(10) default '0',
547
548 UNIQUE KEY ss_row_id (ss_row_id)
549
550 ) TYPE=InnoDB;
551
552 --
553 -- Stores an ID for every time any article is visited;
554 -- depending on $wgHitcounterUpdateFreq, it is
555 -- periodically cleared and the page_counter column
556 -- in the page table updated for the all articles
557 -- that have been visited.)
558 --
559 CREATE TABLE /*$wgDBprefix*/hitcounter (
560 hc_id int unsigned NOT NULL
561 ) TYPE=HEAP MAX_ROWS=25000;
562
563
564 --
565 -- The internet is full of jerks, alas. Sometimes it's handy
566 -- to block a vandal or troll account.
567 --
568 CREATE TABLE /*$wgDBprefix*/ipblocks (
569 -- Primary key, introduced for privacy.
570 ipb_id int(8) NOT NULL auto_increment,
571
572 -- Blocked IP address in dotted-quad form or user name.
573 ipb_address tinyblob NOT NULL,
574
575 -- Blocked user ID or 0 for IP blocks.
576 ipb_user int(8) unsigned NOT NULL default '0',
577
578 -- User ID who made the block.
579 ipb_by int(8) unsigned NOT NULL default '0',
580
581 -- Text comment made by blocker.
582 ipb_reason tinyblob NOT NULL,
583
584 -- Creation (or refresh) date in standard YMDHMS form.
585 -- IP blocks expire automatically.
586 ipb_timestamp char(14) binary NOT NULL default '',
587
588 -- Indicates that the IP address was banned because a banned
589 -- user accessed a page through it. If this is 1, ipb_address
590 -- will be hidden, and the block identified by block ID number.
591 ipb_auto bool NOT NULL default 0,
592
593 -- If set to 1, block applies only to logged-out users
594 ipb_anon_only bool NOT NULL default 0,
595
596 -- Block prevents account creation from matching IP addresses
597 ipb_create_account bool NOT NULL default 1,
598
599 -- Block triggers autoblocks
600 ipb_enable_autoblock bool NOT NULL default '1',
601
602 -- Time at which the block will expire.
603 ipb_expiry char(14) binary NOT NULL default '',
604
605 -- Start and end of an address range, in hexadecimal
606 -- Size chosen to allow IPv6
607 ipb_range_start tinyblob NOT NULL,
608 ipb_range_end tinyblob NOT NULL,
609
610 PRIMARY KEY ipb_id (ipb_id),
611
612 -- Unique index to support "user already blocked" messages
613 -- Any new options which prevent collisions should be included
614 UNIQUE INDEX ipb_address (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only),
615
616 INDEX ipb_user (ipb_user),
617 INDEX ipb_range (ipb_range_start(8), ipb_range_end(8)),
618 INDEX ipb_timestamp (ipb_timestamp),
619 INDEX ipb_expiry (ipb_expiry)
620
621 ) TYPE=InnoDB;
622
623
624 --
625 -- Uploaded images and other files.
626 --
627 CREATE TABLE /*$wgDBprefix*/image (
628 -- Filename.
629 -- This is also the title of the associated description page,
630 -- which will be in namespace 6 (NS_IMAGE).
631 img_name varchar(255) binary NOT NULL default '',
632
633 -- File size in bytes.
634 img_size int(8) unsigned NOT NULL default '0',
635
636 -- For images, size in pixels.
637 img_width int(5) NOT NULL default '0',
638 img_height int(5) NOT NULL default '0',
639
640 -- Extracted EXIF metadata stored as a serialized PHP array.
641 img_metadata mediumblob NOT NULL,
642
643 -- For images, bits per pixel if known.
644 img_bits int(3) NOT NULL default '0',
645
646 -- Media type as defined by the MEDIATYPE_xxx constants
647 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
648
649 -- major part of a MIME media type as defined by IANA
650 -- see http://www.iana.org/assignments/media-types/
651 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
652
653 -- minor part of a MIME media type as defined by IANA
654 -- the minor parts are not required to adher to any standard
655 -- but should be consistent throughout the database
656 -- see http://www.iana.org/assignments/media-types/
657 img_minor_mime varchar(32) NOT NULL default "unknown",
658
659 -- Description field as entered by the uploader.
660 -- This is displayed in image upload history and logs.
661 img_description tinyblob NOT NULL,
662
663 -- user_id and user_name of uploader.
664 img_user int(5) unsigned NOT NULL default '0',
665 img_user_text varchar(255) binary NOT NULL,
666
667 -- Time of the upload.
668 img_timestamp char(14) binary NOT NULL default '',
669
670 PRIMARY KEY img_name (img_name),
671
672 -- Used by Special:Imagelist for sort-by-size
673 INDEX img_size (img_size),
674
675 -- Used by Special:Newimages and Special:Imagelist
676 INDEX img_timestamp (img_timestamp)
677
678 ) TYPE=InnoDB;
679
680 --
681 -- Previous revisions of uploaded files.
682 -- Awkwardly, image rows have to be moved into
683 -- this table at re-upload time.
684 --
685 CREATE TABLE /*$wgDBprefix*/oldimage (
686 -- Base filename: key to image.img_name
687 oi_name varchar(255) binary NOT NULL default '',
688
689 -- Filename of the archived file.
690 -- This is generally a timestamp and '!' prepended to the base name.
691 oi_archive_name varchar(255) binary NOT NULL default '',
692
693 -- Other fields as in image...
694 oi_size int(8) unsigned NOT NULL default 0,
695 oi_width int(5) NOT NULL default 0,
696 oi_height int(5) NOT NULL default 0,
697 oi_bits int(3) NOT NULL default 0,
698 oi_description tinyblob NOT NULL,
699 oi_user int(5) unsigned NOT NULL default '0',
700 oi_user_text varchar(255) binary NOT NULL,
701 oi_timestamp char(14) binary NOT NULL default '',
702
703 INDEX oi_name (oi_name(10))
704
705 ) TYPE=InnoDB;
706
707 --
708 -- Record of deleted file data
709 --
710 CREATE TABLE /*$wgDBprefix*/filearchive (
711 -- Unique row id
712 fa_id int NOT NULL auto_increment,
713
714 -- Original base filename; key to image.img_name, page.page_title, etc
715 fa_name varchar(255) binary NOT NULL default '',
716
717 -- Filename of archived file, if an old revision
718 fa_archive_name varchar(255) binary default '',
719
720 -- Which storage bin (directory tree or object store) the file data
721 -- is stored in. Should be 'deleted' for files that have been deleted;
722 -- any other bin is not yet in use.
723 fa_storage_group varchar(16),
724
725 -- SHA-1 of the file contents plus extension, used as a key for storage.
726 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
727 --
728 -- If NULL, the file was missing at deletion time or has been purged
729 -- from the archival storage.
730 fa_storage_key varchar(64) binary default '',
731
732 -- Deletion information, if this file is deleted.
733 fa_deleted_user int,
734 fa_deleted_timestamp char(14) binary default '',
735 fa_deleted_reason text,
736
737 -- Duped fields from image
738 fa_size int(8) unsigned default '0',
739 fa_width int(5) default '0',
740 fa_height int(5) default '0',
741 fa_metadata mediumblob,
742 fa_bits int(3) default '0',
743 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
744 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
745 fa_minor_mime varchar(32) default "unknown",
746 fa_description tinyblob,
747 fa_user int(5) unsigned default '0',
748 fa_user_text varchar(255) binary,
749 fa_timestamp char(14) binary default '',
750
751 PRIMARY KEY (fa_id),
752 INDEX (fa_name, fa_timestamp), -- pick out by image name
753 INDEX (fa_storage_group, fa_storage_key), -- pick out dupe files
754 INDEX (fa_deleted_timestamp), -- sort by deletion time
755 INDEX (fa_deleted_user) -- sort by deleter
756
757 ) TYPE=InnoDB;
758
759 --
760 -- Primarily a summary table for Special:Recentchanges,
761 -- this table contains some additional info on edits from
762 -- the last few days, see Article::editUpdates()
763 --
764 CREATE TABLE /*$wgDBprefix*/recentchanges (
765 rc_id int(8) NOT NULL auto_increment,
766 rc_timestamp varchar(14) binary NOT NULL default '',
767 rc_cur_time varchar(14) binary NOT NULL default '',
768
769 -- As in revision
770 rc_user int(10) unsigned NOT NULL default '0',
771 rc_user_text varchar(255) binary NOT NULL,
772
773 -- When pages are renamed, their RC entries do _not_ change.
774 rc_namespace int NOT NULL default '0',
775 rc_title varchar(255) binary NOT NULL default '',
776
777 -- as in revision...
778 rc_comment varchar(255) binary NOT NULL default '',
779 rc_minor tinyint(3) unsigned NOT NULL default '0',
780
781 -- Edits by user accounts with the 'bot' rights key are
782 -- marked with a 1 here, and will be hidden from the
783 -- default view.
784 rc_bot tinyint(3) unsigned NOT NULL default '0',
785
786 rc_new tinyint(3) unsigned NOT NULL default '0',
787
788 -- Key to page_id (was cur_id prior to 1.5).
789 -- This will keep links working after moves while
790 -- retaining the at-the-time name in the changes list.
791 rc_cur_id int(10) unsigned NOT NULL default '0',
792
793 -- rev_id of the given revision
794 rc_this_oldid int(10) unsigned NOT NULL default '0',
795
796 -- rev_id of the prior revision, for generating diff links.
797 rc_last_oldid int(10) unsigned NOT NULL default '0',
798
799 -- These may no longer be used, with the new move log.
800 rc_type tinyint(3) unsigned NOT NULL default '0',
801 rc_moved_to_ns tinyint(3) unsigned NOT NULL default '0',
802 rc_moved_to_title varchar(255) binary NOT NULL default '',
803
804 -- If the Recent Changes Patrol option is enabled,
805 -- users may mark edits as having been reviewed to
806 -- remove a warning flag on the RC list.
807 -- A value of 1 indicates the page has been reviewed.
808 rc_patrolled tinyint(3) unsigned NOT NULL default '0',
809
810 -- Recorded IP address the edit was made from, if the
811 -- $wgPutIPinRC option is enabled.
812 rc_ip char(15) NOT NULL default '',
813
814 -- Text length in characters before
815 -- and after the edit
816 rc_old_len int(10),
817 rc_new_len int(10),
818
819 PRIMARY KEY rc_id (rc_id),
820 INDEX rc_timestamp (rc_timestamp),
821 INDEX rc_namespace_title (rc_namespace, rc_title),
822 INDEX rc_cur_id (rc_cur_id),
823 INDEX new_name_timestamp (rc_new,rc_namespace,rc_timestamp),
824 INDEX rc_ip (rc_ip),
825 INDEX rc_ns_usertext (rc_namespace, rc_user_text),
826 INDEX rc_user_text (rc_user_text, rc_timestamp)
827
828 ) TYPE=InnoDB;
829
830 CREATE TABLE /*$wgDBprefix*/watchlist (
831 -- Key to user.user_id
832 wl_user int(5) unsigned NOT NULL,
833
834 -- Key to page_namespace/page_title
835 -- Note that users may watch pages which do not exist yet,
836 -- or existed in the past but have been deleted.
837 wl_namespace int NOT NULL default '0',
838 wl_title varchar(255) binary NOT NULL default '',
839
840 -- Timestamp when user was last sent a notification e-mail;
841 -- cleared when the user visits the page.
842 wl_notificationtimestamp varchar(14) binary,
843
844 UNIQUE KEY (wl_user, wl_namespace, wl_title),
845 KEY namespace_title (wl_namespace, wl_title)
846
847 ) TYPE=InnoDB;
848
849
850 --
851 -- Used by the math module to keep track
852 -- of previously-rendered items.
853 --
854 CREATE TABLE /*$wgDBprefix*/math (
855 -- Binary MD5 hash of the latex fragment, used as an identifier key.
856 math_inputhash varchar(16) NOT NULL,
857
858 -- Not sure what this is, exactly...
859 math_outputhash varchar(16) NOT NULL,
860
861 -- texvc reports how well it thinks the HTML conversion worked;
862 -- if it's a low level the PNG rendering may be preferred.
863 math_html_conservativeness tinyint(1) NOT NULL,
864
865 -- HTML output from texvc, if any
866 math_html text,
867
868 -- MathML output from texvc, if any
869 math_mathml text,
870
871 UNIQUE KEY math_inputhash (math_inputhash)
872
873 ) TYPE=InnoDB;
874
875 --
876 -- When using the default MySQL search backend, page titles
877 -- and text are munged to strip markup, do Unicode case folding,
878 -- and prepare the result for MySQL's fulltext index.
879 --
880 -- This table must be MyISAM; InnoDB does not support the needed
881 -- fulltext index.
882 --
883 CREATE TABLE /*$wgDBprefix*/searchindex (
884 -- Key to page_id
885 si_page int(8) unsigned NOT NULL,
886
887 -- Munged version of title
888 si_title varchar(255) NOT NULL default '',
889
890 -- Munged version of body text
891 si_text mediumtext NOT NULL,
892
893 UNIQUE KEY (si_page),
894 FULLTEXT si_title (si_title),
895 FULLTEXT si_text (si_text)
896
897 ) TYPE=MyISAM;
898
899 --
900 -- Recognized interwiki link prefixes
901 --
902 CREATE TABLE /*$wgDBprefix*/interwiki (
903 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
904 iw_prefix char(32) NOT NULL,
905
906 -- The URL of the wiki, with "$1" as a placeholder for an article name.
907 -- Any spaces in the name will be transformed to underscores before
908 -- insertion.
909 iw_url char(127) NOT NULL,
910
911 -- A boolean value indicating whether the wiki is in this project
912 -- (used, for example, to detect redirect loops)
913 iw_local bool NOT NULL,
914
915 -- Boolean value indicating whether interwiki transclusions are allowed.
916 iw_trans tinyint(1) NOT NULL default 0,
917
918 UNIQUE KEY iw_prefix (iw_prefix)
919
920 ) TYPE=InnoDB;
921
922 --
923 -- Used for caching expensive grouped queries
924 --
925 CREATE TABLE /*$wgDBprefix*/querycache (
926 -- A key name, generally the base name of of the special page.
927 qc_type char(32) NOT NULL,
928
929 -- Some sort of stored value. Sizes, counts...
930 qc_value int(5) unsigned NOT NULL default '0',
931
932 -- Target namespace+title
933 qc_namespace int NOT NULL default '0',
934 qc_title char(255) binary NOT NULL default '',
935
936 KEY (qc_type,qc_value)
937
938 ) TYPE=InnoDB;
939
940 --
941 -- For a few generic cache operations if not using Memcached
942 --
943 CREATE TABLE /*$wgDBprefix*/objectcache (
944 keyname char(255) binary NOT NULL default '',
945 value mediumblob,
946 exptime datetime,
947 UNIQUE KEY (keyname),
948 KEY (exptime)
949
950 ) TYPE=InnoDB;
951
952 --
953 -- Cache of interwiki transclusion
954 --
955 CREATE TABLE /*$wgDBprefix*/transcache (
956 tc_url varchar(255) NOT NULL,
957 tc_contents text,
958 tc_time int NOT NULL,
959 UNIQUE INDEX tc_url_idx (tc_url)
960 ) TYPE=InnoDB;
961
962 CREATE TABLE /*$wgDBprefix*/logging (
963 -- Symbolic keys for the general log type and the action type
964 -- within the log. The output format will be controlled by the
965 -- action field, but only the type controls categorization.
966 log_type char(10) NOT NULL default '',
967 log_action char(10) NOT NULL default '',
968
969 -- Timestamp. Duh.
970 log_timestamp char(14) NOT NULL default '19700101000000',
971
972 -- The user who performed this action; key to user_id
973 log_user int unsigned NOT NULL default 0,
974
975 -- Key to the page affected. Where a user is the target,
976 -- this will point to the user page.
977 log_namespace int NOT NULL default 0,
978 log_title varchar(255) binary NOT NULL default '',
979
980 -- Freeform text. Interpreted as edit history comments.
981 log_comment varchar(255) NOT NULL default '',
982
983 -- LF separated list of miscellaneous parameters
984 log_params blob NOT NULL,
985
986 -- Log ID, for referring to this specific log entry, probably for deletion and such.
987 log_id int unsigned not null auto_increment,
988
989 PRIMARY KEY log_id (log_id),
990 KEY type_time (log_type, log_timestamp),
991 KEY user_time (log_user, log_timestamp),
992 KEY page_time (log_namespace, log_title, log_timestamp),
993 KEY times (log_timestamp)
994
995 ) TYPE=InnoDB;
996
997 CREATE TABLE /*$wgDBprefix*/trackbacks (
998 tb_id int auto_increment,
999 tb_page int REFERENCES page(page_id) ON DELETE CASCADE,
1000 tb_title varchar(255) NOT NULL,
1001 tb_url varchar(255) NOT NULL,
1002 tb_ex text,
1003 tb_name varchar(255),
1004
1005 PRIMARY KEY (tb_id),
1006 INDEX (tb_page)
1007 ) TYPE=InnoDB;
1008
1009
1010 -- Jobs performed by parallel apache threads or a command-line daemon
1011 CREATE TABLE /*$wgDBprefix*/job (
1012 job_id int(9) unsigned NOT NULL auto_increment,
1013
1014 -- Command name, currently only refreshLinks is defined
1015 job_cmd varchar(255) NOT NULL default '',
1016
1017 -- Namespace and title to act on
1018 -- Should be 0 and '' if the command does not operate on a title
1019 job_namespace int NOT NULL,
1020 job_title varchar(255) binary NOT NULL,
1021
1022 -- Any other parameters to the command
1023 -- Presently unused, format undefined
1024 job_params blob NOT NULL,
1025
1026 PRIMARY KEY job_id (job_id),
1027 KEY (job_cmd, job_namespace, job_title)
1028 ) TYPE=InnoDB;
1029
1030
1031 -- Details of updates to cached special pages
1032 CREATE TABLE /*$wgDBprefix*/querycache_info (
1033
1034 -- Special page name
1035 -- Corresponds to a qc_type value
1036 qci_type varchar(32) NOT NULL default '',
1037
1038 -- Timestamp of last update
1039 qci_timestamp char(14) NOT NULL default '19700101000000',
1040
1041 UNIQUE KEY ( qci_type )
1042
1043 ) TYPE=InnoDB;
1044
1045 -- For each redirect, this table contains exactly one row defining its target
1046 CREATE TABLE /*$wgDBprefix*/redirect (
1047 -- Key to the page_id of the redirect page
1048 rd_from int(8) unsigned NOT NULL default '0',
1049
1050 -- Key to page_namespace/page_title of the target page.
1051 -- The target page may or may not exist, and due to renames
1052 -- and deletions may refer to different page records as time
1053 -- goes by.
1054 rd_namespace int NOT NULL default '0',
1055 rd_title varchar(255) binary NOT NULL default '',
1056
1057 PRIMARY KEY rd_from (rd_from),
1058 KEY rd_ns_title (rd_namespace,rd_title,rd_from)
1059 ) TYPE=InnoDB;
1060
1061 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1062 CREATE TABLE /*$wgDBprefix*/querycachetwo (
1063 -- A key name, generally the base name of of the special page.
1064 qcc_type char(32) NOT NULL,
1065
1066 -- Some sort of stored value. Sizes, counts...
1067 qcc_value int(5) unsigned NOT NULL default '0',
1068
1069 -- Target namespace+title
1070 qcc_namespace int NOT NULL default '0',
1071 qcc_title char(255) binary NOT NULL default '',
1072
1073 -- Target namespace+title2
1074 qcc_namespacetwo int NOT NULL default '0',
1075 qcc_titletwo char(255) binary NOT NULL default '',
1076
1077 KEY qcc_type (qcc_type,qcc_value),
1078 KEY qcc_title (qcc_type,qcc_namespace,qcc_title),
1079 KEY qcc_titletwo (qcc_type,qcc_namespacetwo,qcc_titletwo)
1080
1081 ) TYPE=InnoDB;
1082
1083 --- Used for storing page restrictions (i.e. protection levels)
1084 CREATE TABLE /*$wgDBprefix*/page_restrictions (
1085 -- Page to apply restrictions to (Foreign Key to page).
1086 pr_page int(8) NOT NULL,
1087 -- The protection type (edit, move, etc)
1088 pr_type varchar(255) NOT NULL,
1089 -- The protection level (Sysop, autoconfirmed, etc)
1090 pr_level varchar(255) NOT NULL,
1091 -- Whether or not to cascade the protection down to pages transcluded.
1092 pr_cascade tinyint(4) NOT NULL,
1093 -- Field for future support of per-user restriction.
1094 pr_user int(8) NULL,
1095 -- Field for time-limited protection.
1096 pr_expiry char(14) binary NULL,
1097 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1098 pr_id int unsigned not null auto_increment,
1099
1100 PRIMARY KEY pr_pagetype (pr_page,pr_type),
1101
1102 UNIQUE KEY pr_id (pr_id),
1103 KEY pr_page (pr_page),
1104 KEY pr_typelevel (pr_type,pr_level),
1105 KEY pr_level (pr_level),
1106 KEY pr_cascade (pr_cascade)
1107 ) TYPE=InnoDB;
1108
1109 -- vim: sw=2 sts=2 et