Support plural for 'linkstoimage', 'redirectstofile' and 'duplicatesoffile'
[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 BINARY or VARBINARY 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 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 binary(14),
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 binary(14) 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 binary(32) 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 binary(14),
105
106 -- Randomly generated token created when the e-mail address
107 -- is set and a confirmation test mail sent.
108 user_email_token binary(32),
109
110 -- Expiration date for the user_email_token
111 user_email_token_expires binary(14),
112
113 -- Timestamp of account registration.
114 -- Accounts predating this schema addition may contain NULL.
115 user_registration binary(14),
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 ) /*$wgDBTableOptions*/;
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 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 varbinary(16) NOT NULL default '',
156
157 PRIMARY KEY (ug_user,ug_group),
158 KEY (ug_group)
159 ) /*$wgDBTableOptions*/;
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 NOT NULL default '0',
166 -- If the user is an anonymous user their IP address is stored here
167 -- since the user_id of 0 is ambiguous
168 user_ip varbinary(40) NOT NULL default '',
169 -- The highest timestamp of revisions of the talk page viewed
170 -- by this user
171 user_last_timestamp binary(14) NOT NULL default '',
172 INDEX user_id (user_id),
173 INDEX user_ip (user_ip)
174
175 ) /*$wgDBTableOptions*/;
176
177
178 --
179 -- Core of the wiki: each page has an entry here which identifies
180 -- it by title and contains some essential metadata.
181 --
182 CREATE TABLE /*$wgDBprefix*/page (
183 -- Unique identifier number. The page_id will be preserved across
184 -- edits and rename operations, but not deletions and recreations.
185 page_id int unsigned NOT NULL auto_increment,
186
187 -- A page name is broken into a namespace and a title.
188 -- The namespace keys are UI-language-independent constants,
189 -- defined in includes/Defines.php
190 page_namespace int NOT NULL,
191
192 -- The rest of the title, as text.
193 -- Spaces are transformed into underscores in title storage.
194 page_title varchar(255) binary NOT NULL,
195
196 -- Comma-separated set of permission keys indicating who
197 -- can move or edit the page.
198 page_restrictions tinyblob NOT NULL,
199
200 -- Number of times this page has been viewed.
201 page_counter bigint unsigned NOT NULL default '0',
202
203 -- 1 indicates the article is a redirect.
204 page_is_redirect tinyint unsigned NOT NULL default '0',
205
206 -- 1 indicates this is a new entry, with only one edit.
207 -- Not all pages with one edit are new pages.
208 page_is_new tinyint unsigned NOT NULL default '0',
209
210 -- Random value between 0 and 1, used for Special:Randompage
211 page_random real unsigned NOT NULL,
212
213 -- This timestamp is updated whenever the page changes in
214 -- a way requiring it to be re-rendered, invalidating caches.
215 -- Aside from editing this includes permission changes,
216 -- creation or deletion of linked pages, and alteration
217 -- of contained templates.
218 page_touched binary(14) NOT NULL default '',
219
220 -- Handy key to revision.rev_id of the current revision.
221 -- This may be 0 during page creation, but that shouldn't
222 -- happen outside of a transaction... hopefully.
223 page_latest int unsigned NOT NULL,
224
225 -- Uncompressed length in bytes of the page's current source text.
226 page_len int unsigned NOT NULL,
227
228 PRIMARY KEY page_id (page_id),
229 UNIQUE INDEX name_title (page_namespace,page_title),
230
231 -- Special-purpose indexes
232 INDEX (page_random),
233 INDEX (page_len)
234
235 ) /*$wgDBTableOptions*/;
236
237 --
238 -- Every edit of a page creates also a revision row.
239 -- This stores metadata about the revision, and a reference
240 -- to the text storage backend.
241 --
242 CREATE TABLE /*$wgDBprefix*/revision (
243 rev_id int unsigned NOT NULL auto_increment,
244
245 -- Key to page_id. This should _never_ be invalid.
246 rev_page int unsigned NOT NULL,
247
248 -- Key to text.old_id, where the actual bulk text is stored.
249 -- It's possible for multiple revisions to use the same text,
250 -- for instance revisions where only metadata is altered
251 -- or a rollback to a previous version.
252 rev_text_id int unsigned NOT NULL,
253
254 -- Text comment summarizing the change.
255 -- This text is shown in the history and other changes lists,
256 -- rendered in a subset of wiki markup by Linker::formatComment()
257 rev_comment tinyblob NOT NULL,
258
259 -- Key to user.user_id of the user who made this edit.
260 -- Stores 0 for anonymous edits and for some mass imports.
261 rev_user int unsigned NOT NULL default '0',
262
263 -- Text username or IP address of the editor.
264 rev_user_text varchar(255) binary NOT NULL default '',
265
266 -- Timestamp
267 rev_timestamp binary(14) NOT NULL default '',
268
269 -- Records whether the user marked the 'minor edit' checkbox.
270 -- Many automated edits are marked as minor.
271 rev_minor_edit tinyint unsigned NOT NULL default '0',
272
273 -- Not yet used; reserved for future changes to the deletion system.
274 rev_deleted tinyint unsigned NOT NULL default '0',
275
276 -- Length of this revision in bytes
277 rev_len int unsigned,
278
279 -- Key to revision.rev_id
280 -- This field is used to add support for a tree structure (The Adjacency List Model)
281 rev_parent_id int unsigned default NULL,
282
283 PRIMARY KEY rev_page_id (rev_page, rev_id),
284 UNIQUE INDEX rev_id (rev_id),
285 INDEX rev_timestamp (rev_timestamp),
286 INDEX page_timestamp (rev_page,rev_timestamp),
287 INDEX user_timestamp (rev_user,rev_timestamp),
288 INDEX usertext_timestamp (rev_user_text,rev_timestamp)
289
290 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
291 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
292
293 --
294 -- Holds text of individual page revisions.
295 --
296 -- Field names are a holdover from the 'old' revisions table in
297 -- MediaWiki 1.4 and earlier: an upgrade will transform that
298 -- table into the 'text' table to minimize unnecessary churning
299 -- and downtime. If upgrading, the other fields will be left unused.
300 --
301 CREATE TABLE /*$wgDBprefix*/text (
302 -- Unique text storage key number.
303 -- Note that the 'oldid' parameter used in URLs does *not*
304 -- refer to this number anymore, but to rev_id.
305 --
306 -- revision.rev_text_id is a key to this column
307 old_id int unsigned NOT NULL auto_increment,
308
309 -- Depending on the contents of the old_flags field, the text
310 -- may be convenient plain text, or it may be funkily encoded.
311 old_text mediumblob NOT NULL,
312
313 -- Comma-separated list of flags:
314 -- gzip: text is compressed with PHP's gzdeflate() function.
315 -- utf8: text was stored as UTF-8.
316 -- If $wgLegacyEncoding option is on, rows *without* this flag
317 -- will be converted to UTF-8 transparently at load time.
318 -- object: text field contained a serialized PHP object.
319 -- The object either contains multiple versions compressed
320 -- together to achieve a better compression ratio, or it refers
321 -- to another row where the text can be found.
322 old_flags tinyblob NOT NULL,
323
324 PRIMARY KEY old_id (old_id)
325
326 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=10240;
327 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
328
329 --
330 -- Holding area for deleted articles, which may be viewed
331 -- or restored by admins through the Special:Undelete interface.
332 -- The fields generally correspond to the page, revision, and text
333 -- fields, with several caveats.
334 --
335 CREATE TABLE /*$wgDBprefix*/archive (
336 ar_namespace int NOT NULL default '0',
337 ar_title varchar(255) binary NOT NULL default '',
338
339 -- Newly deleted pages will not store text in this table,
340 -- but will reference the separately existing text rows.
341 -- This field is retained for backwards compatibility,
342 -- so old archived pages will remain accessible after
343 -- upgrading from 1.4 to 1.5.
344 -- Text may be gzipped or otherwise funky.
345 ar_text mediumblob NOT NULL,
346
347 -- Basic revision stuff...
348 ar_comment tinyblob NOT NULL,
349 ar_user int unsigned NOT NULL default '0',
350 ar_user_text varchar(255) binary NOT NULL,
351 ar_timestamp binary(14) NOT NULL default '',
352 ar_minor_edit tinyint NOT NULL default '0',
353
354 -- See ar_text note.
355 ar_flags tinyblob NOT NULL,
356
357 -- When revisions are deleted, their unique rev_id is stored
358 -- here so it can be retained after undeletion. This is necessary
359 -- to retain permalinks to given revisions after accidental delete
360 -- cycles or messy operations like history merges.
361 --
362 -- Old entries from 1.4 will be NULL here, and a new rev_id will
363 -- be created on undeletion for those revisions.
364 ar_rev_id int unsigned,
365
366 -- For newly deleted revisions, this is the text.old_id key to the
367 -- actual stored text. To avoid breaking the block-compression scheme
368 -- and otherwise making storage changes harder, the actual text is
369 -- *not* deleted from the text table, merely hidden by removal of the
370 -- page and revision entries.
371 --
372 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
373 -- ar_text and ar_flags fields will be used to create a new text
374 -- row upon undeletion.
375 ar_text_id int unsigned,
376
377 -- rev_deleted for archives
378 ar_deleted tinyint unsigned NOT NULL default '0',
379
380 -- Length of this revision in bytes
381 ar_len int unsigned,
382
383 -- Reference to page_id. Useful for sysadmin fixing of large pages
384 -- merged together in the archives, or for cleanly restoring a page
385 -- at its original ID number if possible.
386 --
387 -- Will be NULL for pages deleted prior to 1.11.
388 ar_page_id int unsigned,
389
390 -- Original previous revision
391 ar_parent_id int unsigned default NULL,
392
393 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp),
394 KEY usertext_timestamp (ar_user_text,ar_timestamp)
395
396 ) /*$wgDBTableOptions*/;
397
398
399 --
400 -- Track page-to-page hyperlinks within the wiki.
401 --
402 CREATE TABLE /*$wgDBprefix*/pagelinks (
403 -- Key to the page_id of the page containing the link.
404 pl_from int unsigned NOT NULL default '0',
405
406 -- Key to page_namespace/page_title of the target page.
407 -- The target page may or may not exist, and due to renames
408 -- and deletions may refer to different page records as time
409 -- goes by.
410 pl_namespace int NOT NULL default '0',
411 pl_title varchar(255) binary NOT NULL default '',
412
413 UNIQUE KEY pl_from (pl_from,pl_namespace,pl_title),
414 KEY (pl_namespace,pl_title,pl_from)
415
416 ) /*$wgDBTableOptions*/;
417
418
419 --
420 -- Track template inclusions.
421 --
422 CREATE TABLE /*$wgDBprefix*/templatelinks (
423 -- Key to the page_id of the page containing the link.
424 tl_from int unsigned NOT NULL default '0',
425
426 -- Key to page_namespace/page_title of the target page.
427 -- The target page may or may not exist, and due to renames
428 -- and deletions may refer to different page records as time
429 -- goes by.
430 tl_namespace int NOT NULL default '0',
431 tl_title varchar(255) binary NOT NULL default '',
432
433 UNIQUE KEY tl_from (tl_from,tl_namespace,tl_title),
434 KEY (tl_namespace,tl_title,tl_from)
435
436 ) /*$wgDBTableOptions*/;
437
438 --
439 -- Track links to images *used inline*
440 -- We don't distinguish live from broken links here, so
441 -- they do not need to be changed on upload/removal.
442 --
443 CREATE TABLE /*$wgDBprefix*/imagelinks (
444 -- Key to page_id of the page containing the image / media link.
445 il_from int unsigned NOT NULL default '0',
446
447 -- Filename of target image.
448 -- This is also the page_title of the file's description page;
449 -- all such pages are in namespace 6 (NS_IMAGE).
450 il_to varchar(255) binary NOT NULL default '',
451
452 UNIQUE KEY il_from (il_from,il_to),
453 KEY (il_to,il_from)
454
455 ) /*$wgDBTableOptions*/;
456
457 --
458 -- Track category inclusions *used inline*
459 -- This tracks a single level of category membership
460 -- (folksonomic tagging, really).
461 --
462 CREATE TABLE /*$wgDBprefix*/categorylinks (
463 -- Key to page_id of the page defined as a category member.
464 cl_from int unsigned NOT NULL default '0',
465
466 -- Name of the category.
467 -- This is also the page_title of the category's description page;
468 -- all such pages are in namespace 14 (NS_CATEGORY).
469 cl_to varchar(255) binary NOT NULL default '',
470
471 -- The title of the linking page, or an optional override
472 -- to determine sort order. Sorting is by binary order, which
473 -- isn't always ideal, but collations seem to be an exciting
474 -- and dangerous new world in MySQL... The sortkey is updated
475 -- if no override exists and cl_from is renamed.
476 --
477 -- Truncate so that the cl_sortkey key fits in 1000 bytes
478 -- (MyISAM 5 with server_character_set=utf8)
479 cl_sortkey varchar(70) binary NOT NULL default '',
480
481 -- This isn't really used at present. Provided for an optional
482 -- sorting method by approximate addition time.
483 cl_timestamp timestamp NOT NULL,
484
485 UNIQUE KEY cl_from (cl_from,cl_to),
486
487 -- We always sort within a given category...
488 KEY cl_sortkey (cl_to,cl_sortkey,cl_from),
489
490 -- Not really used?
491 KEY cl_timestamp (cl_to,cl_timestamp)
492
493 ) /*$wgDBTableOptions*/;
494
495 --
496 -- Track all existing categories. Something is a category if 1) it has an en-
497 -- try somewhere in categorylinks, or 2) it once did. Categories might not
498 -- have corresponding pages, so they need to be tracked separately.
499 --
500 CREATE TABLE /*$wgDBprefix*/category (
501 -- Primary key
502 cat_id int unsigned NOT NULL auto_increment,
503
504 -- Name of the category, in the same form as page_title (with underscores).
505 -- If there is a category page corresponding to this category, by definition,
506 -- it has this name (in the Category namespace).
507 cat_title varchar(255) binary NOT NULL,
508
509 -- The numbers of member pages (including categories and media), subcatego-
510 -- ries, and Image: namespace members, respectively. These are signed to
511 -- make underflow more obvious. We make the first number include the second
512 -- two for better sorting: subtracting for display is easy, adding for order-
513 -- ing is not.
514 cat_pages int signed NOT NULL default 0,
515 cat_subcats int signed NOT NULL default 0,
516 cat_files int signed NOT NULL default 0,
517
518 -- Reserved for future use
519 cat_hidden tinyint unsigned NOT NULL default 0,
520
521 PRIMARY KEY (cat_id),
522 UNIQUE KEY (cat_title),
523
524 -- For Special:Mostlinkedcategories
525 KEY (cat_pages)
526 ) /*$wgDBTableOptions*/;
527
528 --
529 -- Track links to external URLs
530 --
531 CREATE TABLE /*$wgDBprefix*/externallinks (
532 -- page_id of the referring page
533 el_from int unsigned NOT NULL default '0',
534
535 -- The URL
536 el_to blob NOT NULL,
537
538 -- In the case of HTTP URLs, this is the URL with any username or password
539 -- removed, and with the labels in the hostname reversed and converted to
540 -- lower case. An extra dot is added to allow for matching of either
541 -- example.com or *.example.com in a single scan.
542 -- Example:
543 -- http://user:password@sub.example.com/page.html
544 -- becomes
545 -- http://com.example.sub./page.html
546 -- which allows for fast searching for all pages under example.com with the
547 -- clause:
548 -- WHERE el_index LIKE 'http://com.example.%'
549 el_index blob NOT NULL,
550
551 KEY (el_from, el_to(40)),
552 KEY (el_to(60), el_from),
553 KEY (el_index(60))
554 ) /*$wgDBTableOptions*/;
555
556 --
557 -- Track interlanguage links
558 --
559 CREATE TABLE /*$wgDBprefix*/langlinks (
560 -- page_id of the referring page
561 ll_from int unsigned NOT NULL default '0',
562
563 -- Language code of the target
564 ll_lang varbinary(20) NOT NULL default '',
565
566 -- Title of the target, including namespace
567 ll_title varchar(255) binary NOT NULL default '',
568
569 UNIQUE KEY (ll_from, ll_lang),
570 KEY (ll_lang, ll_title)
571 ) /*$wgDBTableOptions*/;
572
573 --
574 -- Contains a single row with some aggregate info
575 -- on the state of the site.
576 --
577 CREATE TABLE /*$wgDBprefix*/site_stats (
578 -- The single row should contain 1 here.
579 ss_row_id int unsigned NOT NULL,
580
581 -- Total number of page views, if hit counters are enabled.
582 ss_total_views bigint unsigned default '0',
583
584 -- Total number of edits performed.
585 ss_total_edits bigint unsigned default '0',
586
587 -- An approximate count of pages matching the following criteria:
588 -- * in namespace 0
589 -- * not a redirect
590 -- * contains the text '[['
591 -- See Article::isCountable() in includes/Article.php
592 ss_good_articles bigint unsigned default '0',
593
594 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
595 ss_total_pages bigint default '-1',
596
597 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
598 ss_users bigint default '-1',
599
600 -- Deprecated, no longer updated as of 1.5
601 ss_admins int default '-1',
602
603 -- Number of images, equivalent to SELECT COUNT(*) FROM image
604 ss_images int default '0',
605
606 UNIQUE KEY ss_row_id (ss_row_id)
607
608 ) /*$wgDBTableOptions*/;
609
610 --
611 -- Stores an ID for every time any article is visited;
612 -- depending on $wgHitcounterUpdateFreq, it is
613 -- periodically cleared and the page_counter column
614 -- in the page table updated for the all articles
615 -- that have been visited.)
616 --
617 CREATE TABLE /*$wgDBprefix*/hitcounter (
618 hc_id int unsigned NOT NULL
619 ) TYPE=HEAP MAX_ROWS=25000;
620
621
622 --
623 -- The internet is full of jerks, alas. Sometimes it's handy
624 -- to block a vandal or troll account.
625 --
626 CREATE TABLE /*$wgDBprefix*/ipblocks (
627 -- Primary key, introduced for privacy.
628 ipb_id int NOT NULL auto_increment,
629
630 -- Blocked IP address in dotted-quad form or user name.
631 ipb_address tinyblob NOT NULL,
632
633 -- Blocked user ID or 0 for IP blocks.
634 ipb_user int unsigned NOT NULL default '0',
635
636 -- User ID who made the block.
637 ipb_by int unsigned NOT NULL default '0',
638
639 -- User name of blocker
640 ipb_by_text varchar(255) binary NOT NULL default '',
641
642 -- Text comment made by blocker.
643 ipb_reason tinyblob NOT NULL,
644
645 -- Creation (or refresh) date in standard YMDHMS form.
646 -- IP blocks expire automatically.
647 ipb_timestamp binary(14) NOT NULL default '',
648
649 -- Indicates that the IP address was banned because a banned
650 -- user accessed a page through it. If this is 1, ipb_address
651 -- will be hidden, and the block identified by block ID number.
652 ipb_auto bool NOT NULL default 0,
653
654 -- If set to 1, block applies only to logged-out users
655 ipb_anon_only bool NOT NULL default 0,
656
657 -- Block prevents account creation from matching IP addresses
658 ipb_create_account bool NOT NULL default 1,
659
660 -- Block triggers autoblocks
661 ipb_enable_autoblock bool NOT NULL default '1',
662
663 -- Time at which the block will expire.
664 -- May be "infinity"
665 ipb_expiry varbinary(14) NOT NULL default '',
666
667 -- Start and end of an address range, in hexadecimal
668 -- Size chosen to allow IPv6
669 ipb_range_start tinyblob NOT NULL,
670 ipb_range_end tinyblob NOT NULL,
671
672 -- Flag for entries hidden from users and Sysops
673 ipb_deleted bool NOT NULL default 0,
674
675 -- Block prevents user from accessing Special:Emailuser
676 ipb_block_email bool NOT NULL default 0,
677
678 PRIMARY KEY ipb_id (ipb_id),
679
680 -- Unique index to support "user already blocked" messages
681 -- Any new options which prevent collisions should be included
682 UNIQUE INDEX ipb_address (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only),
683
684 INDEX ipb_user (ipb_user),
685 INDEX ipb_range (ipb_range_start(8), ipb_range_end(8)),
686 INDEX ipb_timestamp (ipb_timestamp),
687 INDEX ipb_expiry (ipb_expiry)
688
689 ) /*$wgDBTableOptions*/;
690
691
692 --
693 -- Uploaded images and other files.
694 --
695 CREATE TABLE /*$wgDBprefix*/image (
696 -- Filename.
697 -- This is also the title of the associated description page,
698 -- which will be in namespace 6 (NS_IMAGE).
699 img_name varchar(255) binary NOT NULL default '',
700
701 -- File size in bytes.
702 img_size int unsigned NOT NULL default '0',
703
704 -- For images, size in pixels.
705 img_width int NOT NULL default '0',
706 img_height int NOT NULL default '0',
707
708 -- Extracted EXIF metadata stored as a serialized PHP array.
709 img_metadata mediumblob NOT NULL,
710
711 -- For images, bits per pixel if known.
712 img_bits int NOT NULL default '0',
713
714 -- Media type as defined by the MEDIATYPE_xxx constants
715 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
716
717 -- major part of a MIME media type as defined by IANA
718 -- see http://www.iana.org/assignments/media-types/
719 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
720
721 -- minor part of a MIME media type as defined by IANA
722 -- the minor parts are not required to adher to any standard
723 -- but should be consistent throughout the database
724 -- see http://www.iana.org/assignments/media-types/
725 img_minor_mime varbinary(32) NOT NULL default "unknown",
726
727 -- Description field as entered by the uploader.
728 -- This is displayed in image upload history and logs.
729 img_description tinyblob NOT NULL,
730
731 -- user_id and user_name of uploader.
732 img_user int unsigned NOT NULL default '0',
733 img_user_text varchar(255) binary NOT NULL,
734
735 -- Time of the upload.
736 img_timestamp varbinary(14) NOT NULL default '',
737
738 -- SHA-1 content hash in base-36
739 img_sha1 varbinary(32) NOT NULL default '',
740
741 PRIMARY KEY img_name (img_name),
742
743 INDEX img_usertext_timestamp (img_user_text,img_timestamp),
744 -- Used by Special:Imagelist for sort-by-size
745 INDEX img_size (img_size),
746 -- Used by Special:Newimages and Special:Imagelist
747 INDEX img_timestamp (img_timestamp),
748
749 -- For future use
750 INDEX img_sha1 (img_sha1)
751
752
753 ) /*$wgDBTableOptions*/;
754
755 --
756 -- Previous revisions of uploaded files.
757 -- Awkwardly, image rows have to be moved into
758 -- this table at re-upload time.
759 --
760 CREATE TABLE /*$wgDBprefix*/oldimage (
761 -- Base filename: key to image.img_name
762 oi_name varchar(255) binary NOT NULL default '',
763
764 -- Filename of the archived file.
765 -- This is generally a timestamp and '!' prepended to the base name.
766 oi_archive_name varchar(255) binary NOT NULL default '',
767
768 -- Other fields as in image...
769 oi_size int unsigned NOT NULL default 0,
770 oi_width int NOT NULL default 0,
771 oi_height int NOT NULL default 0,
772 oi_bits int NOT NULL default 0,
773 oi_description tinyblob NOT NULL,
774 oi_user int unsigned NOT NULL default '0',
775 oi_user_text varchar(255) binary NOT NULL,
776 oi_timestamp binary(14) NOT NULL default '',
777
778 oi_metadata mediumblob NOT NULL,
779 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
780 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
781 oi_minor_mime varbinary(32) NOT NULL default "unknown",
782 oi_deleted tinyint unsigned NOT NULL default '0',
783 oi_sha1 varbinary(32) NOT NULL default '',
784
785 INDEX oi_usertext_timestamp (oi_user_text,oi_timestamp),
786 INDEX oi_name_timestamp (oi_name,oi_timestamp),
787 -- oi_archive_name truncated to 14 to avoid key length overflow
788 INDEX oi_name_archive_name (oi_name,oi_archive_name(14)),
789 INDEX oi_sha1 (oi_sha1)
790
791 ) /*$wgDBTableOptions*/;
792
793 --
794 -- Record of deleted file data
795 --
796 CREATE TABLE /*$wgDBprefix*/filearchive (
797 -- Unique row id
798 fa_id int NOT NULL auto_increment,
799
800 -- Original base filename; key to image.img_name, page.page_title, etc
801 fa_name varchar(255) binary NOT NULL default '',
802
803 -- Filename of archived file, if an old revision
804 fa_archive_name varchar(255) binary default '',
805
806 -- Which storage bin (directory tree or object store) the file data
807 -- is stored in. Should be 'deleted' for files that have been deleted;
808 -- any other bin is not yet in use.
809 fa_storage_group varbinary(16),
810
811 -- SHA-1 of the file contents plus extension, used as a key for storage.
812 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
813 --
814 -- If NULL, the file was missing at deletion time or has been purged
815 -- from the archival storage.
816 fa_storage_key varbinary(64) default '',
817
818 -- Deletion information, if this file is deleted.
819 fa_deleted_user int,
820 fa_deleted_timestamp binary(14) default '',
821 fa_deleted_reason text,
822
823 -- Duped fields from image
824 fa_size int unsigned default '0',
825 fa_width int default '0',
826 fa_height int default '0',
827 fa_metadata mediumblob,
828 fa_bits int default '0',
829 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
830 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
831 fa_minor_mime varbinary(32) default "unknown",
832 fa_description tinyblob,
833 fa_user int unsigned default '0',
834 fa_user_text varchar(255) binary,
835 fa_timestamp binary(14) default '',
836
837 -- Visibility of deleted revisions, bitfield
838 fa_deleted tinyint unsigned NOT NULL default '0',
839
840 PRIMARY KEY (fa_id),
841 INDEX (fa_name, fa_timestamp), -- pick out by image name
842 INDEX (fa_storage_group, fa_storage_key), -- pick out dupe files
843 INDEX (fa_deleted_timestamp), -- sort by deletion time
844 INDEX fa_user_timestamp (fa_user_text,fa_timestamp) -- sort by uploader
845
846 ) /*$wgDBTableOptions*/;
847
848 --
849 -- Primarily a summary table for Special:Recentchanges,
850 -- this table contains some additional info on edits from
851 -- the last few days, see Article::editUpdates()
852 --
853 CREATE TABLE /*$wgDBprefix*/recentchanges (
854 rc_id int NOT NULL auto_increment,
855 rc_timestamp varbinary(14) NOT NULL default '',
856 rc_cur_time varbinary(14) NOT NULL default '',
857
858 -- As in revision
859 rc_user int unsigned NOT NULL default '0',
860 rc_user_text varchar(255) binary NOT NULL,
861
862 -- When pages are renamed, their RC entries do _not_ change.
863 rc_namespace int NOT NULL default '0',
864 rc_title varchar(255) binary NOT NULL default '',
865
866 -- as in revision...
867 rc_comment varchar(255) binary NOT NULL default '',
868 rc_minor tinyint unsigned NOT NULL default '0',
869
870 -- Edits by user accounts with the 'bot' rights key are
871 -- marked with a 1 here, and will be hidden from the
872 -- default view.
873 rc_bot tinyint unsigned NOT NULL default '0',
874
875 rc_new tinyint unsigned NOT NULL default '0',
876
877 -- Key to page_id (was cur_id prior to 1.5).
878 -- This will keep links working after moves while
879 -- retaining the at-the-time name in the changes list.
880 rc_cur_id int unsigned NOT NULL default '0',
881
882 -- rev_id of the given revision
883 rc_this_oldid int unsigned NOT NULL default '0',
884
885 -- rev_id of the prior revision, for generating diff links.
886 rc_last_oldid int unsigned NOT NULL default '0',
887
888 -- These may no longer be used, with the new move log.
889 rc_type tinyint unsigned NOT NULL default '0',
890 rc_moved_to_ns tinyint unsigned NOT NULL default '0',
891 rc_moved_to_title varchar(255) binary NOT NULL default '',
892
893 -- If the Recent Changes Patrol option is enabled,
894 -- users may mark edits as having been reviewed to
895 -- remove a warning flag on the RC list.
896 -- A value of 1 indicates the page has been reviewed.
897 rc_patrolled tinyint unsigned NOT NULL default '0',
898
899 -- Recorded IP address the edit was made from, if the
900 -- $wgPutIPinRC option is enabled.
901 rc_ip varbinary(40) NOT NULL default '',
902
903 -- Text length in characters before
904 -- and after the edit
905 rc_old_len int,
906 rc_new_len int,
907
908 -- Visibility of deleted revisions, bitfield
909 rc_deleted tinyint unsigned NOT NULL default '0',
910
911 -- Value corresonding to log_id, specific log entries
912 rc_logid int unsigned NOT NULL default '0',
913 -- Store log type info here, or null
914 rc_log_type varbinary(255) NULL default NULL,
915 -- Store log action or null
916 rc_log_action varbinary(255) NULL default NULL,
917 -- Log params
918 rc_params blob NULL,
919
920 PRIMARY KEY rc_id (rc_id),
921 INDEX rc_timestamp (rc_timestamp),
922 INDEX rc_namespace_title (rc_namespace, rc_title),
923 INDEX rc_cur_id (rc_cur_id),
924 INDEX new_name_timestamp (rc_new,rc_namespace,rc_timestamp),
925 INDEX rc_ip (rc_ip),
926 INDEX rc_ns_usertext (rc_namespace, rc_user_text),
927 INDEX rc_user_text (rc_user_text, rc_timestamp)
928
929 ) /*$wgDBTableOptions*/;
930
931 CREATE TABLE /*$wgDBprefix*/watchlist (
932 -- Key to user.user_id
933 wl_user int unsigned NOT NULL,
934
935 -- Key to page_namespace/page_title
936 -- Note that users may watch pages which do not exist yet,
937 -- or existed in the past but have been deleted.
938 wl_namespace int NOT NULL default '0',
939 wl_title varchar(255) binary NOT NULL default '',
940
941 -- Timestamp when user was last sent a notification e-mail;
942 -- cleared when the user visits the page.
943 wl_notificationtimestamp varbinary(14),
944
945 UNIQUE KEY (wl_user, wl_namespace, wl_title),
946 KEY namespace_title (wl_namespace, wl_title)
947
948 ) /*$wgDBTableOptions*/;
949
950
951 --
952 -- Used by the math module to keep track
953 -- of previously-rendered items.
954 --
955 CREATE TABLE /*$wgDBprefix*/math (
956 -- Binary MD5 hash of the latex fragment, used as an identifier key.
957 math_inputhash varbinary(16) NOT NULL,
958
959 -- Not sure what this is, exactly...
960 math_outputhash varbinary(16) NOT NULL,
961
962 -- texvc reports how well it thinks the HTML conversion worked;
963 -- if it's a low level the PNG rendering may be preferred.
964 math_html_conservativeness tinyint NOT NULL,
965
966 -- HTML output from texvc, if any
967 math_html text,
968
969 -- MathML output from texvc, if any
970 math_mathml text,
971
972 UNIQUE KEY math_inputhash (math_inputhash)
973
974 ) /*$wgDBTableOptions*/;
975
976 --
977 -- When using the default MySQL search backend, page titles
978 -- and text are munged to strip markup, do Unicode case folding,
979 -- and prepare the result for MySQL's fulltext index.
980 --
981 -- This table must be MyISAM; InnoDB does not support the needed
982 -- fulltext index.
983 --
984 CREATE TABLE /*$wgDBprefix*/searchindex (
985 -- Key to page_id
986 si_page int unsigned NOT NULL,
987
988 -- Munged version of title
989 si_title varchar(255) NOT NULL default '',
990
991 -- Munged version of body text
992 si_text mediumtext NOT NULL,
993
994 UNIQUE KEY (si_page),
995 FULLTEXT si_title (si_title),
996 FULLTEXT si_text (si_text)
997
998 ) TYPE=MyISAM;
999
1000 --
1001 -- Recognized interwiki link prefixes
1002 --
1003 CREATE TABLE /*$wgDBprefix*/interwiki (
1004 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
1005 iw_prefix varchar(32) NOT NULL,
1006
1007 -- The URL of the wiki, with "$1" as a placeholder for an article name.
1008 -- Any spaces in the name will be transformed to underscores before
1009 -- insertion.
1010 iw_url blob NOT NULL,
1011
1012 -- A boolean value indicating whether the wiki is in this project
1013 -- (used, for example, to detect redirect loops)
1014 iw_local bool NOT NULL,
1015
1016 -- Boolean value indicating whether interwiki transclusions are allowed.
1017 iw_trans tinyint NOT NULL default 0,
1018
1019 UNIQUE KEY iw_prefix (iw_prefix)
1020
1021 ) /*$wgDBTableOptions*/;
1022
1023 --
1024 -- Used for caching expensive grouped queries
1025 --
1026 CREATE TABLE /*$wgDBprefix*/querycache (
1027 -- A key name, generally the base name of of the special page.
1028 qc_type varbinary(32) NOT NULL,
1029
1030 -- Some sort of stored value. Sizes, counts...
1031 qc_value int unsigned NOT NULL default '0',
1032
1033 -- Target namespace+title
1034 qc_namespace int NOT NULL default '0',
1035 qc_title varchar(255) binary NOT NULL default '',
1036
1037 KEY (qc_type,qc_value)
1038
1039 ) /*$wgDBTableOptions*/;
1040
1041 --
1042 -- For a few generic cache operations if not using Memcached
1043 --
1044 CREATE TABLE /*$wgDBprefix*/objectcache (
1045 keyname varbinary(255) NOT NULL default '',
1046 value mediumblob,
1047 exptime datetime,
1048 UNIQUE KEY (keyname),
1049 KEY (exptime)
1050
1051 ) /*$wgDBTableOptions*/;
1052
1053 --
1054 -- Cache of interwiki transclusion
1055 --
1056 CREATE TABLE /*$wgDBprefix*/transcache (
1057 tc_url varbinary(255) NOT NULL,
1058 tc_contents text,
1059 tc_time int NOT NULL,
1060 UNIQUE INDEX tc_url_idx (tc_url)
1061 ) /*$wgDBTableOptions*/;
1062
1063 CREATE TABLE /*$wgDBprefix*/logging (
1064 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1065 log_id int unsigned NOT NULL auto_increment,
1066
1067 -- Symbolic keys for the general log type and the action type
1068 -- within the log. The output format will be controlled by the
1069 -- action field, but only the type controls categorization.
1070 log_type varbinary(10) NOT NULL default '',
1071 log_action varbinary(10) NOT NULL default '',
1072
1073 -- Timestamp. Duh.
1074 log_timestamp binary(14) NOT NULL default '19700101000000',
1075
1076 -- The user who performed this action; key to user_id
1077 log_user int unsigned NOT NULL default 0,
1078
1079 -- Key to the page affected. Where a user is the target,
1080 -- this will point to the user page.
1081 log_namespace int NOT NULL default 0,
1082 log_title varchar(255) binary NOT NULL default '',
1083
1084 -- Freeform text. Interpreted as edit history comments.
1085 log_comment varchar(255) NOT NULL default '',
1086
1087 -- LF separated list of miscellaneous parameters
1088 log_params blob NOT NULL,
1089
1090 -- rev_deleted for logs
1091 log_deleted tinyint unsigned NOT NULL default '0',
1092
1093 PRIMARY KEY log_id (log_id),
1094 KEY type_time (log_type, log_timestamp),
1095 KEY user_time (log_user, log_timestamp),
1096 KEY page_time (log_namespace, log_title, log_timestamp),
1097 KEY times (log_timestamp)
1098
1099 ) /*$wgDBTableOptions*/;
1100
1101 CREATE TABLE /*$wgDBprefix*/trackbacks (
1102 tb_id int auto_increment,
1103 tb_page int REFERENCES /*$wgDBprefix*/page(page_id) ON DELETE CASCADE,
1104 tb_title varchar(255) NOT NULL,
1105 tb_url blob NOT NULL,
1106 tb_ex text,
1107 tb_name varchar(255),
1108
1109 PRIMARY KEY (tb_id),
1110 INDEX (tb_page)
1111 ) /*$wgDBTableOptions*/;
1112
1113
1114 -- Jobs performed by parallel apache threads or a command-line daemon
1115 CREATE TABLE /*$wgDBprefix*/job (
1116 job_id int unsigned NOT NULL auto_increment,
1117
1118 -- Command name
1119 -- Limited to 60 to prevent key length overflow
1120 job_cmd varbinary(60) NOT NULL default '',
1121
1122 -- Namespace and title to act on
1123 -- Should be 0 and '' if the command does not operate on a title
1124 job_namespace int NOT NULL,
1125 job_title varchar(255) binary NOT NULL,
1126
1127 -- Any other parameters to the command
1128 -- Presently unused, format undefined
1129 job_params blob NOT NULL,
1130
1131 PRIMARY KEY job_id (job_id),
1132 KEY (job_cmd, job_namespace, job_title)
1133 ) /*$wgDBTableOptions*/;
1134
1135
1136 -- Details of updates to cached special pages
1137 CREATE TABLE /*$wgDBprefix*/querycache_info (
1138
1139 -- Special page name
1140 -- Corresponds to a qc_type value
1141 qci_type varbinary(32) NOT NULL default '',
1142
1143 -- Timestamp of last update
1144 qci_timestamp binary(14) NOT NULL default '19700101000000',
1145
1146 UNIQUE KEY ( qci_type )
1147
1148 ) /*$wgDBTableOptions*/;
1149
1150 -- For each redirect, this table contains exactly one row defining its target
1151 CREATE TABLE /*$wgDBprefix*/redirect (
1152 -- Key to the page_id of the redirect page
1153 rd_from int unsigned NOT NULL default '0',
1154
1155 -- Key to page_namespace/page_title of the target page.
1156 -- The target page may or may not exist, and due to renames
1157 -- and deletions may refer to different page records as time
1158 -- goes by.
1159 rd_namespace int NOT NULL default '0',
1160 rd_title varchar(255) binary NOT NULL default '',
1161
1162 PRIMARY KEY rd_from (rd_from),
1163 KEY rd_ns_title (rd_namespace,rd_title,rd_from)
1164 ) /*$wgDBTableOptions*/;
1165
1166 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1167 CREATE TABLE /*$wgDBprefix*/querycachetwo (
1168 -- A key name, generally the base name of of the special page.
1169 qcc_type varbinary(32) NOT NULL,
1170
1171 -- Some sort of stored value. Sizes, counts...
1172 qcc_value int unsigned NOT NULL default '0',
1173
1174 -- Target namespace+title
1175 qcc_namespace int NOT NULL default '0',
1176 qcc_title varchar(255) binary NOT NULL default '',
1177
1178 -- Target namespace+title2
1179 qcc_namespacetwo int NOT NULL default '0',
1180 qcc_titletwo varchar(255) binary NOT NULL default '',
1181
1182 KEY qcc_type (qcc_type,qcc_value),
1183 KEY qcc_title (qcc_type,qcc_namespace,qcc_title),
1184 KEY qcc_titletwo (qcc_type,qcc_namespacetwo,qcc_titletwo)
1185
1186 ) /*$wgDBTableOptions*/;
1187
1188 -- Used for storing page restrictions (i.e. protection levels)
1189 CREATE TABLE /*$wgDBprefix*/page_restrictions (
1190 -- Page to apply restrictions to (Foreign Key to page).
1191 pr_page int NOT NULL,
1192 -- The protection type (edit, move, etc)
1193 pr_type varbinary(60) NOT NULL,
1194 -- The protection level (Sysop, autoconfirmed, etc)
1195 pr_level varbinary(60) NOT NULL,
1196 -- Whether or not to cascade the protection down to pages transcluded.
1197 pr_cascade tinyint NOT NULL,
1198 -- Field for future support of per-user restriction.
1199 pr_user int NULL,
1200 -- Field for time-limited protection.
1201 pr_expiry varbinary(14) NULL,
1202 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1203 pr_id int unsigned NOT NULL auto_increment,
1204
1205 PRIMARY KEY pr_pagetype (pr_page,pr_type),
1206
1207 UNIQUE KEY pr_id (pr_id),
1208 KEY pr_typelevel (pr_type,pr_level),
1209 KEY pr_level (pr_level),
1210 KEY pr_cascade (pr_cascade)
1211 ) /*$wgDBTableOptions*/;
1212
1213 -- Protected titles - nonexistent pages that have been protected
1214 CREATE TABLE /*$wgDBprefix*/protected_titles (
1215 pt_namespace int NOT NULL,
1216 pt_title varchar(255) binary NOT NULL,
1217 pt_user int unsigned NOT NULL,
1218 pt_reason tinyblob,
1219 pt_timestamp binary(14) NOT NULL,
1220 pt_expiry varbinary(14) NOT NULL default '',
1221 pt_create_perm varbinary(60) NOT NULL,
1222 PRIMARY KEY (pt_namespace,pt_title),
1223 KEY pt_timestamp (pt_timestamp)
1224 ) /*$wgDBTableOptions*/;
1225
1226 -- Name/value pairs indexed by page_id
1227 CREATE TABLE /*$wgDBprefix*/page_props (
1228 pp_page int NOT NULL,
1229 pp_propname varbinary(60) NOT NULL,
1230 pp_value blob NOT NULL,
1231
1232 PRIMARY KEY (pp_page,pp_propname)
1233 ) /*$wgDBTableOptions*/;
1234
1235 -- A table to log updates, one text key row per update.
1236 CREATE TABLE /*$wgDBprefix*/updatelog (
1237 ul_key varchar(255) NOT NULL,
1238 PRIMARY KEY (ul_key)
1239 ) /*$wgDBTableOptions*/;
1240
1241 -- vim: sw=2 sts=2 et