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