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