whitespace consistency
[lhc/web/wiklou.git] / maintenance / tables.sql
1 -- SQL to create the initial tables for the MediaWiki database.
2 -- This is read and executed by the install script; you should
3 -- not have to run it by itself unless doing a manual install.
4
5 --
6 -- General notes:
7 --
8 -- If possible, create tables as InnoDB to benefit from the
9 -- superior resiliency against crashes and ability to read
10 -- during writes (and write during reads!)
11 --
12 -- Only the 'searchindex' table requires MyISAM due to the
13 -- requirement for fulltext index support, which is missing
14 -- from InnoDB.
15 --
16 --
17 -- The MySQL table backend for MediaWiki currently uses
18 -- 14-character CHAR or VARCHAR fields to store timestamps.
19 -- The format is YYYYMMDDHHMMSS, which is derived from the
20 -- text format of MySQL's TIMESTAMP fields.
21 --
22 -- Historically TIMESTAMP fields were used, but abandoned
23 -- in early 2002 after a lot of trouble with the fields
24 -- auto-updating.
25 --
26 -- The Postgres backend uses DATETIME fields for timestamps,
27 -- and we will migrate the MySQL definitions at some point as
28 -- well.
29 --
30 --
31 -- The /*$wgDBprefix*/ comments in this and other files are
32 -- replaced with the defined table prefix by the installer
33 -- and updater scripts. If you are installing or running
34 -- updates manually, you will need to manually insert the
35 -- table prefix if any when running these scripts.
36 --
37
38
39 --
40 -- The user table contains basic account information,
41 -- authentication keys, etc.
42 --
43 -- Some multi-wiki sites may share a single central user table
44 -- between separate wikis using the $wgSharedDB setting.
45 --
46 -- Note that when a external authentication plugin is used,
47 -- user table entries still need to be created to store
48 -- preferences and to key tracking information in the other
49 -- tables.
50 --
51 CREATE TABLE /*$wgDBprefix*/user (
52 user_id int(5) unsigned NOT NULL auto_increment,
53
54 -- Usernames must be unique, must not be in the form of
55 -- an IP address. _Shouldn't_ allow slashes or case
56 -- conflicts. Spaces are allowed, and are _not_ converted
57 -- to underscores like titles. See the User::newFromName() for
58 -- the specific tests that usernames have to pass.
59 user_name varchar(255) binary NOT NULL default '',
60
61 -- Optional 'real name' to be displayed in credit listings
62 user_real_name varchar(255) binary NOT NULL default '',
63
64 -- Password hashes, normally hashed like so:
65 -- MD5(CONCAT(user_id,'-',MD5(plaintext_password))), see
66 -- wfEncryptPassword() in GlobalFunctions.php
67 user_password tinyblob NOT NULL,
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 char(14) binary,
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 char(14) binary 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 char(32) binary 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 char(14) binary,
105
106 -- Randomly generated token created when the e-mail address
107 -- is set and a confirmation test mail sent.
108 user_email_token char(32) binary,
109
110 -- Expiration date for the user_email_token
111 user_email_token_expires char(14) binary,
112
113 -- Timestamp of account registration.
114 -- Accounts predating this schema addition may contain NULL.
115 user_registration char(14) binary,
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(5) 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 char(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(5) 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 varchar(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(8) 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(20) unsigned NOT NULL default '0',
199
200 -- 1 indicates the article is a redirect.
201 page_is_redirect tinyint(1) 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(1) 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 char(14) binary 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(8) unsigned NOT NULL,
221
222 -- Uncompressed length in bytes of the page's current source text.
223 page_len int(8) 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(8) unsigned NOT NULL auto_increment,
241
242 -- Key to page_id. This should _never_ be invalid.
243 rev_page int(8) 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(8) 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(5) 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 char(14) binary 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(1) unsigned NOT NULL default '0',
269
270 -- Not yet used; reserved for future changes to the deletion system.
271 rev_deleted tinyint(1) unsigned NOT NULL default '0',
272
273 -- Length of this revision in bytes
274 rev_len int(8) 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(8) 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(8) 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(5) unsigned NOT NULL default '0',
347 ar_user_text varchar(255) binary NOT NULL,
348 ar_timestamp char(14) binary NOT NULL default '',
349 ar_minor_edit tinyint(1) 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(8) 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(8) unsigned,
373
374 -- rev_deleted for archives
375 ar_deleted tinyint(1) unsigned NOT NULL default '0',
376
377 -- Length of this revision in bytes
378 ar_len int(8) unsigned,
379
380 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp)
381
382 ) /*$wgDBTableOptions*/;
383
384
385 --
386 -- Track page-to-page hyperlinks within the wiki.
387 --
388 CREATE TABLE /*$wgDBprefix*/pagelinks (
389 -- Key to the page_id of the page containing the link.
390 pl_from int(8) unsigned NOT NULL default '0',
391
392 -- Key to page_namespace/page_title of the target page.
393 -- The target page may or may not exist, and due to renames
394 -- and deletions may refer to different page records as time
395 -- goes by.
396 pl_namespace int NOT NULL default '0',
397 pl_title varchar(255) binary NOT NULL default '',
398
399 UNIQUE KEY pl_from (pl_from,pl_namespace,pl_title),
400 KEY (pl_namespace,pl_title,pl_from)
401
402 ) /*$wgDBTableOptions*/;
403
404
405 --
406 -- Track template inclusions.
407 --
408 CREATE TABLE /*$wgDBprefix*/templatelinks (
409 -- Key to the page_id of the page containing the link.
410 tl_from int(8) unsigned NOT NULL default '0',
411
412 -- Key to page_namespace/page_title of the target page.
413 -- The target page may or may not exist, and due to renames
414 -- and deletions may refer to different page records as time
415 -- goes by.
416 tl_namespace int NOT NULL default '0',
417 tl_title varchar(255) binary NOT NULL default '',
418
419 UNIQUE KEY tl_from (tl_from,tl_namespace,tl_title),
420 KEY (tl_namespace,tl_title,tl_from)
421
422 ) /*$wgDBTableOptions*/;
423
424 --
425 -- Track links to images *used inline*
426 -- We don't distinguish live from broken links here, so
427 -- they do not need to be changed on upload/removal.
428 --
429 CREATE TABLE /*$wgDBprefix*/imagelinks (
430 -- Key to page_id of the page containing the image / media link.
431 il_from int(8) unsigned NOT NULL default '0',
432
433 -- Filename of target image.
434 -- This is also the page_title of the file's description page;
435 -- all such pages are in namespace 6 (NS_IMAGE).
436 il_to varchar(255) binary NOT NULL default '',
437
438 UNIQUE KEY il_from (il_from,il_to),
439 KEY (il_to,il_from)
440
441 ) /*$wgDBTableOptions*/;
442
443 --
444 -- Track category inclusions *used inline*
445 -- This tracks a single level of category membership
446 -- (folksonomic tagging, really).
447 --
448 CREATE TABLE /*$wgDBprefix*/categorylinks (
449 -- Key to page_id of the page defined as a category member.
450 cl_from int(8) unsigned NOT NULL default '0',
451
452 -- Name of the category.
453 -- This is also the page_title of the category's description page;
454 -- all such pages are in namespace 14 (NS_CATEGORY).
455 cl_to varchar(255) binary NOT NULL default '',
456
457 -- The title of the linking page, or an optional override
458 -- to determine sort order. Sorting is by binary order, which
459 -- isn't always ideal, but collations seem to be an exciting
460 -- and dangerous new world in MySQL... The sortkey is updated
461 -- if no override exists and cl_from is renamed.
462 --
463 -- For MySQL 4.1+ with charset set to utf8, the sort key *index*
464 -- needs cut to be smaller than 1024 bytes (at 3 bytes per char).
465 -- To sort properly on the shorter key, this field needs to be
466 -- the same shortness.
467 cl_sortkey varchar(86) binary NOT NULL default '',
468
469 -- This isn't really used at present. Provided for an optional
470 -- sorting method by approximate addition time.
471 cl_timestamp timestamp NOT NULL,
472
473 UNIQUE KEY cl_from (cl_from,cl_to),
474
475 -- We always sort within a given category...
476 KEY cl_sortkey (cl_to,cl_sortkey),
477
478 -- Not really used?
479 KEY cl_timestamp (cl_to,cl_timestamp)
480
481 ) /*$wgDBTableOptions*/;
482
483 --
484 -- Track links to external URLs
485 --
486 CREATE TABLE /*$wgDBprefix*/externallinks (
487 -- page_id of the referring page
488 el_from int(8) unsigned NOT NULL default '0',
489
490 -- The URL
491 el_to blob NOT NULL,
492
493 -- In the case of HTTP URLs, this is the URL with any username or password
494 -- removed, and with the labels in the hostname reversed and converted to
495 -- lower case. An extra dot is added to allow for matching of either
496 -- example.com or *.example.com in a single scan.
497 -- Example:
498 -- http://user:password@sub.example.com/page.html
499 -- becomes
500 -- http://com.example.sub./page.html
501 -- which allows for fast searching for all pages under example.com with the
502 -- clause:
503 -- WHERE el_index LIKE 'http://com.example.%'
504 el_index blob NOT NULL,
505
506 KEY (el_from, el_to(40)),
507 KEY (el_to(60), el_from),
508 KEY (el_index(60))
509 ) /*$wgDBTableOptions*/;
510
511 --
512 -- Track interlanguage links
513 --
514 CREATE TABLE /*$wgDBprefix*/langlinks (
515 -- page_id of the referring page
516 ll_from int(8) unsigned NOT NULL default '0',
517
518 -- Language code of the target
519 ll_lang varchar(10) binary NOT NULL default '',
520
521 -- Title of the target, including namespace
522 ll_title varchar(255) binary NOT NULL default '',
523
524 UNIQUE KEY (ll_from, ll_lang),
525 KEY (ll_lang, ll_title)
526 ) /*$wgDBTableOptions*/;
527
528 --
529 -- Contains a single row with some aggregate info
530 -- on the state of the site.
531 --
532 CREATE TABLE /*$wgDBprefix*/site_stats (
533 -- The single row should contain 1 here.
534 ss_row_id int(8) unsigned NOT NULL,
535
536 -- Total number of page views, if hit counters are enabled.
537 ss_total_views bigint(20) unsigned default '0',
538
539 -- Total number of edits performed.
540 ss_total_edits bigint(20) unsigned default '0',
541
542 -- An approximate count of pages matching the following criteria:
543 -- * in namespace 0
544 -- * not a redirect
545 -- * contains the text '[['
546 -- See Article::isCountable() in includes/Article.php
547 ss_good_articles bigint(20) unsigned default '0',
548
549 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
550 ss_total_pages bigint(20) default '-1',
551
552 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
553 ss_users bigint(20) default '-1',
554
555 -- Deprecated, no longer updated as of 1.5
556 ss_admins int(10) default '-1',
557
558 -- Number of images, equivalent to SELECT COUNT(*) FROM image
559 ss_images int(10) default '0',
560
561 UNIQUE KEY ss_row_id (ss_row_id)
562
563 ) /*$wgDBTableOptions*/;
564
565 --
566 -- Stores an ID for every time any article is visited;
567 -- depending on $wgHitcounterUpdateFreq, it is
568 -- periodically cleared and the page_counter column
569 -- in the page table updated for the all articles
570 -- that have been visited.)
571 --
572 CREATE TABLE /*$wgDBprefix*/hitcounter (
573 hc_id int unsigned NOT NULL
574 ) TYPE=HEAP MAX_ROWS=25000;
575
576
577 --
578 -- The internet is full of jerks, alas. Sometimes it's handy
579 -- to block a vandal or troll account.
580 --
581 CREATE TABLE /*$wgDBprefix*/ipblocks (
582 -- Primary key, introduced for privacy.
583 ipb_id int(8) NOT NULL auto_increment,
584
585 -- Blocked IP address in dotted-quad form or user name.
586 ipb_address tinyblob NOT NULL,
587
588 -- Blocked user ID or 0 for IP blocks.
589 ipb_user int(8) unsigned NOT NULL default '0',
590
591 -- User ID who made the block.
592 ipb_by int(8) unsigned NOT NULL default '0',
593
594 -- Text comment made by blocker.
595 ipb_reason tinyblob NOT NULL,
596
597 -- Creation (or refresh) date in standard YMDHMS form.
598 -- IP blocks expire automatically.
599 ipb_timestamp char(14) binary NOT NULL default '',
600
601 -- Indicates that the IP address was banned because a banned
602 -- user accessed a page through it. If this is 1, ipb_address
603 -- will be hidden, and the block identified by block ID number.
604 ipb_auto bool NOT NULL default 0,
605
606 -- If set to 1, block applies only to logged-out users
607 ipb_anon_only bool NOT NULL default 0,
608
609 -- Block prevents account creation from matching IP addresses
610 ipb_create_account bool NOT NULL default 1,
611
612 -- Block triggers autoblocks
613 ipb_enable_autoblock bool NOT NULL default '1',
614
615 -- Time at which the block will expire.
616 ipb_expiry char(14) binary NOT NULL default '',
617
618 -- Start and end of an address range, in hexadecimal
619 -- Size chosen to allow IPv6
620 ipb_range_start tinyblob NOT NULL,
621 ipb_range_end tinyblob NOT NULL,
622
623 -- Flag for entries hidden from users and Sysops
624 ipb_deleted bool NOT NULL default 0,
625
626 -- Block prevents user from accessing Special:Emailuser
627 ipb_block_email bool NOT NULL default 0,
628
629 PRIMARY KEY ipb_id (ipb_id),
630
631 -- Unique index to support "user already blocked" messages
632 -- Any new options which prevent collisions should be included
633 UNIQUE INDEX ipb_address (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only),
634
635 INDEX ipb_user (ipb_user),
636 INDEX ipb_range (ipb_range_start(8), ipb_range_end(8)),
637 INDEX ipb_timestamp (ipb_timestamp),
638 INDEX ipb_expiry (ipb_expiry)
639
640 ) /*$wgDBTableOptions*/;
641
642
643 --
644 -- Uploaded images and other files.
645 --
646 CREATE TABLE /*$wgDBprefix*/image (
647 -- Filename.
648 -- This is also the title of the associated description page,
649 -- which will be in namespace 6 (NS_IMAGE).
650 img_name varchar(255) binary NOT NULL default '',
651
652 -- File size in bytes.
653 img_size int(8) unsigned NOT NULL default '0',
654
655 -- For images, size in pixels.
656 img_width int(5) NOT NULL default '0',
657 img_height int(5) NOT NULL default '0',
658
659 -- Extracted EXIF metadata stored as a serialized PHP array.
660 img_metadata mediumblob NOT NULL,
661
662 -- For images, bits per pixel if known.
663 img_bits int(3) NOT NULL default '0',
664
665 -- Media type as defined by the MEDIATYPE_xxx constants
666 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
667
668 -- major part of a MIME media type as defined by IANA
669 -- see http://www.iana.org/assignments/media-types/
670 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
671
672 -- minor part of a MIME media type as defined by IANA
673 -- the minor parts are not required to adher to any standard
674 -- but should be consistent throughout the database
675 -- see http://www.iana.org/assignments/media-types/
676 img_minor_mime varchar(32) NOT NULL default "unknown",
677
678 -- Description field as entered by the uploader.
679 -- This is displayed in image upload history and logs.
680 img_description tinyblob NOT NULL,
681
682 -- user_id and user_name of uploader.
683 img_user int(5) unsigned NOT NULL default '0',
684 img_user_text varchar(255) binary NOT NULL,
685
686 -- Time of the upload.
687 img_timestamp char(14) binary NOT NULL default '',
688
689 PRIMARY KEY img_name (img_name),
690
691 -- Used by Special:Imagelist for sort-by-size
692 INDEX img_size (img_size),
693
694 -- Used by Special:Newimages and Special:Imagelist
695 INDEX img_timestamp (img_timestamp)
696
697 ) /*$wgDBTableOptions*/;
698
699 --
700 -- Previous revisions of uploaded files.
701 -- Awkwardly, image rows have to be moved into
702 -- this table at re-upload time.
703 --
704 CREATE TABLE /*$wgDBprefix*/oldimage (
705 -- Base filename: key to image.img_name
706 oi_name varchar(255) binary NOT NULL default '',
707
708 -- Filename of the archived file.
709 -- This is generally a timestamp and '!' prepended to the base name.
710 oi_archive_name varchar(255) binary NOT NULL default '',
711
712 -- Other fields as in image...
713 oi_size int(8) unsigned NOT NULL default 0,
714 oi_width int(5) NOT NULL default 0,
715 oi_height int(5) NOT NULL default 0,
716 oi_bits int(3) NOT NULL default 0,
717 oi_description tinyblob NOT NULL,
718 oi_user int(5) unsigned NOT NULL default '0',
719 oi_user_text varchar(255) binary NOT NULL,
720 oi_timestamp char(14) binary NOT NULL default '',
721
722 oi_metadata mediumblob NOT NULL,
723 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
724 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
725 oi_minor_mime varchar(32) NOT NULL default "unknown",
726 oi_deleted tinyint(1) unsigned NOT NULL default '0',
727
728 INDEX oi_name_timestamp (oi_name,oi_timestamp),
729 INDEX oi_name_archive_name (oi_name,oi_archive_name)
730
731 ) /*$wgDBTableOptions*/;
732
733 --
734 -- Record of deleted file data
735 --
736 CREATE TABLE /*$wgDBprefix*/filearchive (
737 -- Unique row id
738 fa_id int NOT NULL auto_increment,
739
740 -- Original base filename; key to image.img_name, page.page_title, etc
741 fa_name varchar(255) binary NOT NULL default '',
742
743 -- Filename of archived file, if an old revision
744 fa_archive_name varchar(255) binary default '',
745
746 -- Which storage bin (directory tree or object store) the file data
747 -- is stored in. Should be 'deleted' for files that have been deleted;
748 -- any other bin is not yet in use.
749 fa_storage_group varchar(16),
750
751 -- SHA-1 of the file contents plus extension, used as a key for storage.
752 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
753 --
754 -- If NULL, the file was missing at deletion time or has been purged
755 -- from the archival storage.
756 fa_storage_key varchar(64) binary default '',
757
758 -- Deletion information, if this file is deleted.
759 fa_deleted_user int,
760 fa_deleted_timestamp char(14) binary default '',
761 fa_deleted_reason text,
762
763 -- Duped fields from image
764 fa_size int(8) unsigned default '0',
765 fa_width int(5) default '0',
766 fa_height int(5) default '0',
767 fa_metadata mediumblob,
768 fa_bits int(3) default '0',
769 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
770 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
771 fa_minor_mime varchar(32) default "unknown",
772 fa_description tinyblob,
773 fa_user int(5) unsigned default '0',
774 fa_user_text varchar(255) binary,
775 fa_timestamp char(14) binary default '',
776
777 -- Visibility of deleted revisions, bitfield
778 fa_deleted tinyint(1) unsigned NOT NULL default '0',
779
780 PRIMARY KEY (fa_id),
781 INDEX (fa_name, fa_timestamp), -- pick out by image name
782 INDEX (fa_storage_group, fa_storage_key), -- pick out dupe files
783 INDEX (fa_deleted_timestamp), -- sort by deletion time
784 INDEX (fa_deleted_user) -- sort by deleter
785
786 ) /*$wgDBTableOptions*/;
787
788 --
789 -- Primarily a summary table for Special:Recentchanges,
790 -- this table contains some additional info on edits from
791 -- the last few days, see Article::editUpdates()
792 --
793 CREATE TABLE /*$wgDBprefix*/recentchanges (
794 rc_id int(8) NOT NULL auto_increment,
795 rc_timestamp varchar(14) binary NOT NULL default '',
796 rc_cur_time varchar(14) binary NOT NULL default '',
797
798 -- As in revision
799 rc_user int(10) unsigned NOT NULL default '0',
800 rc_user_text varchar(255) binary NOT NULL,
801
802 -- When pages are renamed, their RC entries do _not_ change.
803 rc_namespace int NOT NULL default '0',
804 rc_title varchar(255) binary NOT NULL default '',
805
806 -- as in revision...
807 rc_comment varchar(255) binary NOT NULL default '',
808 rc_minor tinyint(3) unsigned NOT NULL default '0',
809
810 -- Edits by user accounts with the 'bot' rights key are
811 -- marked with a 1 here, and will be hidden from the
812 -- default view.
813 rc_bot tinyint(3) unsigned NOT NULL default '0',
814
815 rc_new tinyint(3) unsigned NOT NULL default '0',
816
817 -- Key to page_id (was cur_id prior to 1.5).
818 -- This will keep links working after moves while
819 -- retaining the at-the-time name in the changes list.
820 rc_cur_id int(10) unsigned NOT NULL default '0',
821
822 -- rev_id of the given revision
823 rc_this_oldid int(10) unsigned NOT NULL default '0',
824
825 -- rev_id of the prior revision, for generating diff links.
826 rc_last_oldid int(10) unsigned NOT NULL default '0',
827
828 -- These may no longer be used, with the new move log.
829 rc_type tinyint(3) unsigned NOT NULL default '0',
830 rc_moved_to_ns tinyint(3) unsigned NOT NULL default '0',
831 rc_moved_to_title varchar(255) binary NOT NULL default '',
832
833 -- If the Recent Changes Patrol option is enabled,
834 -- users may mark edits as having been reviewed to
835 -- remove a warning flag on the RC list.
836 -- A value of 1 indicates the page has been reviewed.
837 rc_patrolled tinyint(3) unsigned NOT NULL default '0',
838
839 -- Recorded IP address the edit was made from, if the
840 -- $wgPutIPinRC option is enabled.
841 rc_ip char(15) NOT NULL default '',
842
843 -- Text length in characters before
844 -- and after the edit
845 rc_old_len int(10),
846 rc_new_len int(10),
847
848 -- Visibility of deleted revisions, bitfield
849 rc_deleted tinyint(1) unsigned NOT NULL default '0',
850
851 -- Value corresonding to log_id, specific log entries
852 rc_logid int(10) unsigned NOT NULL default '0',
853 -- Store log type info here, or null
854 rc_log_type varchar(255) binary NULL default NULL,
855 -- Store log action or null
856 rc_log_action varchar(255) binary NULL default NULL,
857 -- Log params
858 rc_params blob NOT NULL default '',
859
860 PRIMARY KEY rc_id (rc_id),
861 INDEX rc_timestamp (rc_timestamp),
862 INDEX rc_namespace_title (rc_namespace, rc_title),
863 INDEX rc_cur_id (rc_cur_id),
864 INDEX new_name_timestamp (rc_new,rc_namespace,rc_timestamp),
865 INDEX rc_ip (rc_ip),
866 INDEX rc_ns_usertext (rc_namespace, rc_user_text),
867 INDEX rc_user_text (rc_user_text, rc_timestamp)
868
869 ) /*$wgDBTableOptions*/;
870
871 CREATE TABLE /*$wgDBprefix*/watchlist (
872 -- Key to user.user_id
873 wl_user int(5) unsigned NOT NULL,
874
875 -- Key to page_namespace/page_title
876 -- Note that users may watch pages which do not exist yet,
877 -- or existed in the past but have been deleted.
878 wl_namespace int NOT NULL default '0',
879 wl_title varchar(255) binary NOT NULL default '',
880
881 -- Timestamp when user was last sent a notification e-mail;
882 -- cleared when the user visits the page.
883 wl_notificationtimestamp varchar(14) binary,
884
885 UNIQUE KEY (wl_user, wl_namespace, wl_title),
886 KEY namespace_title (wl_namespace, wl_title)
887
888 ) /*$wgDBTableOptions*/;
889
890
891 --
892 -- Used by the math module to keep track
893 -- of previously-rendered items.
894 --
895 CREATE TABLE /*$wgDBprefix*/math (
896 -- Binary MD5 hash of the latex fragment, used as an identifier key.
897 math_inputhash varchar(16) NOT NULL,
898
899 -- Not sure what this is, exactly...
900 math_outputhash varchar(16) NOT NULL,
901
902 -- texvc reports how well it thinks the HTML conversion worked;
903 -- if it's a low level the PNG rendering may be preferred.
904 math_html_conservativeness tinyint(1) NOT NULL,
905
906 -- HTML output from texvc, if any
907 math_html text,
908
909 -- MathML output from texvc, if any
910 math_mathml text,
911
912 UNIQUE KEY math_inputhash (math_inputhash)
913
914 ) /*$wgDBTableOptions*/;
915
916 --
917 -- When using the default MySQL search backend, page titles
918 -- and text are munged to strip markup, do Unicode case folding,
919 -- and prepare the result for MySQL's fulltext index.
920 --
921 -- This table must be MyISAM; InnoDB does not support the needed
922 -- fulltext index.
923 --
924 CREATE TABLE /*$wgDBprefix*/searchindex (
925 -- Key to page_id
926 si_page int(8) unsigned NOT NULL,
927
928 -- Munged version of title
929 si_title varchar(255) NOT NULL default '',
930
931 -- Munged version of body text
932 si_text mediumtext NOT NULL,
933
934 UNIQUE KEY (si_page),
935 FULLTEXT si_title (si_title),
936 FULLTEXT si_text (si_text)
937
938 ) TYPE=MyISAM;
939
940 --
941 -- Recognized interwiki link prefixes
942 --
943 CREATE TABLE /*$wgDBprefix*/interwiki (
944 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
945 iw_prefix char(32) NOT NULL,
946
947 -- The URL of the wiki, with "$1" as a placeholder for an article name.
948 -- Any spaces in the name will be transformed to underscores before
949 -- insertion.
950 iw_url varchar(127) NOT NULL,
951
952 -- A boolean value indicating whether the wiki is in this project
953 -- (used, for example, to detect redirect loops)
954 iw_local bool NOT NULL,
955
956 -- Boolean value indicating whether interwiki transclusions are allowed.
957 iw_trans tinyint(1) NOT NULL default 0,
958
959 UNIQUE KEY iw_prefix (iw_prefix)
960
961 ) /*$wgDBTableOptions*/;
962
963 --
964 -- Used for caching expensive grouped queries
965 --
966 CREATE TABLE /*$wgDBprefix*/querycache (
967 -- A key name, generally the base name of of the special page.
968 qc_type varchar(32) binary NOT NULL,
969
970 -- Some sort of stored value. Sizes, counts...
971 qc_value int(5) unsigned NOT NULL default '0',
972
973 -- Target namespace+title
974 qc_namespace int NOT NULL default '0',
975 qc_title varchar(255) binary NOT NULL default '',
976
977 KEY (qc_type,qc_value)
978
979 ) /*$wgDBTableOptions*/;
980
981 --
982 -- For a few generic cache operations if not using Memcached
983 --
984 CREATE TABLE /*$wgDBprefix*/objectcache (
985 keyname varchar(255) binary NOT NULL default '',
986 value mediumblob,
987 exptime datetime,
988 UNIQUE KEY (keyname),
989 KEY (exptime)
990
991 ) /*$wgDBTableOptions*/;
992
993 --
994 -- Cache of interwiki transclusion
995 --
996 CREATE TABLE /*$wgDBprefix*/transcache (
997 tc_url varchar(255) NOT NULL,
998 tc_contents text,
999 tc_time int NOT NULL,
1000 UNIQUE INDEX tc_url_idx (tc_url)
1001 ) /*$wgDBTableOptions*/;
1002
1003 CREATE TABLE /*$wgDBprefix*/logging (
1004 -- Symbolic keys for the general log type and the action type
1005 -- within the log. The output format will be controlled by the
1006 -- action field, but only the type controls categorization.
1007 log_type char(10) NOT NULL default '',
1008 log_action char(10) NOT NULL default '',
1009
1010 -- Timestamp. Duh.
1011 log_timestamp char(14) NOT NULL default '19700101000000',
1012
1013 -- The user who performed this action; key to user_id
1014 log_user int unsigned NOT NULL default 0,
1015
1016 -- Key to the page affected. Where a user is the target,
1017 -- this will point to the user page.
1018 log_namespace int NOT NULL default 0,
1019 log_title varchar(255) binary NOT NULL default '',
1020
1021 -- Freeform text. Interpreted as edit history comments.
1022 log_comment varchar(255) NOT NULL default '',
1023
1024 -- LF separated list of miscellaneous parameters
1025 log_params blob NOT NULL,
1026
1027 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1028 log_id int unsigned NOT NULL auto_increment,
1029
1030 -- rev_deleted for logs
1031 log_deleted tinyint(1) unsigned NOT NULL default '0',
1032
1033 PRIMARY KEY log_id (log_id),
1034 KEY type_time (log_type, log_timestamp),
1035 KEY user_time (log_user, log_timestamp),
1036 KEY page_time (log_namespace, log_title, log_timestamp),
1037 KEY times (log_timestamp)
1038
1039 ) /*$wgDBTableOptions*/;
1040
1041 CREATE TABLE /*$wgDBprefix*/trackbacks (
1042 tb_id int auto_increment,
1043 tb_page int REFERENCES page(page_id) ON DELETE CASCADE,
1044 tb_title varchar(255) NOT NULL,
1045 tb_url varchar(255) NOT NULL,
1046 tb_ex text,
1047 tb_name varchar(255),
1048
1049 PRIMARY KEY (tb_id),
1050 INDEX (tb_page)
1051 ) /*$wgDBTableOptions*/;
1052
1053
1054 -- Jobs performed by parallel apache threads or a command-line daemon
1055 CREATE TABLE /*$wgDBprefix*/job (
1056 job_id int(9) unsigned NOT NULL auto_increment,
1057
1058 -- Command name, currently only refreshLinks is defined
1059 job_cmd varchar(255) NOT NULL default '',
1060
1061 -- Namespace and title to act on
1062 -- Should be 0 and '' if the command does not operate on a title
1063 job_namespace int NOT NULL,
1064 job_title varchar(255) binary NOT NULL,
1065
1066 -- Any other parameters to the command
1067 -- Presently unused, format undefined
1068 job_params blob NOT NULL,
1069
1070 PRIMARY KEY job_id (job_id),
1071 KEY (job_cmd, job_namespace, job_title)
1072 ) /*$wgDBTableOptions*/;
1073
1074
1075 -- Details of updates to cached special pages
1076 CREATE TABLE /*$wgDBprefix*/querycache_info (
1077
1078 -- Special page name
1079 -- Corresponds to a qc_type value
1080 qci_type varchar(32) NOT NULL default '',
1081
1082 -- Timestamp of last update
1083 qci_timestamp char(14) NOT NULL default '19700101000000',
1084
1085 UNIQUE KEY ( qci_type )
1086
1087 ) /*$wgDBTableOptions*/;
1088
1089 -- For each redirect, this table contains exactly one row defining its target
1090 CREATE TABLE /*$wgDBprefix*/redirect (
1091 -- Key to the page_id of the redirect page
1092 rd_from int(8) unsigned NOT NULL default '0',
1093
1094 -- Key to page_namespace/page_title of the target page.
1095 -- The target page may or may not exist, and due to renames
1096 -- and deletions may refer to different page records as time
1097 -- goes by.
1098 rd_namespace int NOT NULL default '0',
1099 rd_title varchar(255) binary NOT NULL default '',
1100
1101 PRIMARY KEY rd_from (rd_from),
1102 KEY rd_ns_title (rd_namespace,rd_title,rd_from)
1103 ) /*$wgDBTableOptions*/;
1104
1105 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1106 CREATE TABLE /*$wgDBprefix*/querycachetwo (
1107 -- A key name, generally the base name of of the special page.
1108 qcc_type varchar(32) NOT NULL,
1109
1110 -- Some sort of stored value. Sizes, counts...
1111 qcc_value int(5) unsigned NOT NULL default '0',
1112
1113 -- Target namespace+title
1114 qcc_namespace int NOT NULL default '0',
1115 qcc_title varchar(255) binary NOT NULL default '',
1116
1117 -- Target namespace+title2
1118 qcc_namespacetwo int NOT NULL default '0',
1119 qcc_titletwo varchar(255) binary NOT NULL default '',
1120
1121 KEY qcc_type (qcc_type,qcc_value),
1122 KEY qcc_title (qcc_type,qcc_namespace,qcc_title),
1123 KEY qcc_titletwo (qcc_type,qcc_namespacetwo,qcc_titletwo)
1124
1125 ) /*$wgDBTableOptions*/;
1126
1127 -- Used for storing page restrictions (i.e. protection levels)
1128 CREATE TABLE /*$wgDBprefix*/page_restrictions (
1129 -- Page to apply restrictions to (Foreign Key to page).
1130 pr_page int(8) NOT NULL,
1131 -- The protection type (edit, move, etc)
1132 pr_type varchar(255) NOT NULL,
1133 -- The protection level (Sysop, autoconfirmed, etc)
1134 pr_level varchar(255) NOT NULL,
1135 -- Whether or not to cascade the protection down to pages transcluded.
1136 pr_cascade tinyint(4) NOT NULL,
1137 -- Field for future support of per-user restriction.
1138 pr_user int(8) NULL,
1139 -- Field for time-limited protection.
1140 pr_expiry char(14) binary NULL,
1141 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1142 pr_id int unsigned NOT NULL auto_increment,
1143
1144 PRIMARY KEY pr_pagetype (pr_page,pr_type),
1145
1146 UNIQUE KEY pr_id (pr_id),
1147 KEY pr_page (pr_page),
1148 KEY pr_typelevel (pr_type,pr_level),
1149 KEY pr_level (pr_level),
1150 KEY pr_cascade (pr_cascade)
1151 ) /*$wgDBTableOptions*/;
1152
1153 -- vim: sw=2 sts=2 et