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