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