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