fname never used
[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 PostgreSQL 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 default '',
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 default '',
76
77 -- Note: email should be restricted, not public info.
78 -- Same with passwords.
79 user_email tinytext NOT NULL default '',
80
81 -- Newline-separated list of name=value defining the user
82 -- preferences
83 user_options blob NOT NULL default '',
84
85 -- This is a timestamp which is updated when a user
86 -- logs in, logs out, changes preferences, or performs
87 -- some other action requiring HTML cache invalidation
88 -- to ensure that the UI is updated.
89 user_touched char(14) binary NOT NULL default '',
90
91 -- A pseudorandomly generated value that is stored in
92 -- a cookie when the "remember password" feature is
93 -- used (previously, a hash of the password was used, but
94 -- this was vulnerable to cookie-stealing attacks)
95 user_token char(32) binary NOT NULL default '',
96
97 -- Initially NULL; when a user's e-mail address has been
98 -- validated by returning with a mailed token, this is
99 -- set to the current timestamp.
100 user_email_authenticated CHAR(14) BINARY,
101
102 -- Randomly generated token created when the e-mail address
103 -- is set and a confirmation test mail sent.
104 user_email_token CHAR(32) BINARY,
105
106 -- Expiration date for the user_email_token
107 user_email_token_expires CHAR(14) BINARY,
108
109 PRIMARY KEY user_id (user_id),
110 UNIQUE INDEX user_name (user_name),
111 INDEX (user_email_token)
112
113 ) TYPE=InnoDB;
114
115 --
116 -- User permissions have been broken out to a separate table;
117 -- this allows sites with a shared user table to have different
118 -- permissions assigned to a user in each project.
119 --
120 -- This table replaces the old user_rights field which used a
121 -- comma-separated blob.
122 --
123 CREATE TABLE /*$wgDBprefix*/user_groups (
124 -- Key to user_id
125 ug_user int(5) unsigned NOT NULL default '0',
126
127 -- Group names are short symbolic string keys.
128 -- The set of group names is open-ended, though in practice
129 -- only some predefined ones are likely to be used.
130 --
131 -- At runtime $wgGroupPermissions will associate group keys
132 -- with particular permissions. A user will have the combined
133 -- permissions of any group they're explicitly in, plus
134 -- the implicit '*' and 'user' groups.
135 ug_group char(16) NOT NULL default '',
136
137 PRIMARY KEY (ug_user,ug_group),
138 KEY (ug_group)
139 ) TYPE=InnoDB;
140
141 -- Stores notifications of user talk page changes, for the display
142 -- of the "you have new messages" box
143 CREATE TABLE /*$wgDBprefix*/user_newtalk (
144 -- Key to user.user_id
145 user_id int(5) NOT NULL default '0',
146 -- If the user is an anonymous user hir IP address is stored here
147 -- since the user_id of 0 is ambiguous
148 user_ip varchar(40) NOT NULL default '',
149 INDEX user_id (user_id),
150 INDEX user_ip (user_ip)
151 );
152
153
154 --
155 -- Core of the wiki: each page has an entry here which identifies
156 -- it by title and contains some essential metadata.
157 --
158 CREATE TABLE /*$wgDBprefix*/page (
159 -- Unique identifier number. The page_id will be preserved across
160 -- edits and rename operations, but not deletions and recreations.
161 page_id int(8) unsigned NOT NULL auto_increment,
162
163 -- A page name is broken into a namespace and a title.
164 -- The namespace keys are UI-language-independent constants,
165 -- defined in includes/Defines.php
166 page_namespace int NOT NULL,
167
168 -- The rest of the title, as text.
169 -- Spaces are transformed into underscores in title storage.
170 page_title varchar(255) binary NOT NULL,
171
172 -- Comma-separated set of permission keys indicating who
173 -- can move or edit the page.
174 page_restrictions tinyblob NOT NULL default '',
175
176 -- Number of times this page has been viewed.
177 page_counter bigint(20) unsigned NOT NULL default '0',
178
179 -- 1 indicates the article is a redirect.
180 page_is_redirect tinyint(1) unsigned NOT NULL default '0',
181
182 -- 1 indicates this is a new entry, with only one edit.
183 -- Not all pages with one edit are new pages.
184 page_is_new tinyint(1) unsigned NOT NULL default '0',
185
186 -- Random value between 0 and 1, used for Special:Randompage
187 page_random real unsigned NOT NULL,
188
189 -- This timestamp is updated whenever the page changes in
190 -- a way requiring it to be re-rendered, invalidating caches.
191 -- Aside from editing this includes permission changes,
192 -- creation or deletion of linked pages, and alteration
193 -- of contained templates.
194 page_touched char(14) binary NOT NULL default '',
195
196 -- Handy key to revision.rev_id of the current revision.
197 -- This may be 0 during page creation, but that shouldn't
198 -- happen outside of a transaction... hopefully.
199 page_latest int(8) unsigned NOT NULL,
200
201 -- Uncompressed length in bytes of the page's current source text.
202 page_len int(8) unsigned NOT NULL,
203
204 PRIMARY KEY page_id (page_id),
205 UNIQUE INDEX name_title (page_namespace,page_title),
206
207 -- Special-purpose indexes
208 INDEX (page_random),
209 INDEX (page_len)
210
211 ) TYPE=InnoDB;
212
213 --
214 -- Every edit of a page creates also a revision row.
215 -- This stores metadata about the revision, and a reference
216 -- to the text storage backend.
217 --
218 CREATE TABLE /*$wgDBprefix*/revision (
219 rev_id int(8) unsigned NOT NULL auto_increment,
220
221 -- Key to page_id. This should _never_ be invalid.
222 rev_page int(8) unsigned NOT NULL,
223
224 -- Key to text.old_id, where the actual bulk text is stored.
225 -- It's possible for multiple revisions to use the same text,
226 -- for instance revisions where only metadata is altered
227 -- or a rollback to a previous version.
228 rev_text_id int(8) unsigned NOT NULL,
229
230 -- Text comment summarizing the change.
231 -- This text is shown in the history and other changes lists,
232 -- rendered in a subset of wiki markup by Linker::formatComment()
233 rev_comment tinyblob NOT NULL default '',
234
235 -- Key to user.user_id of the user who made this edit.
236 -- Stores 0 for anonymous edits and for some mass imports.
237 rev_user int(5) unsigned NOT NULL default '0',
238
239 -- Text username or IP address of the editor.
240 rev_user_text varchar(255) binary NOT NULL default '',
241
242 -- Timestamp
243 rev_timestamp char(14) binary NOT NULL default '',
244
245 -- Records whether the user marked the 'minor edit' checkbox.
246 -- Many automated edits are marked as minor.
247 rev_minor_edit tinyint(1) unsigned NOT NULL default '0',
248
249 -- Not yet used; reserved for future changes to the deletion system.
250 rev_deleted tinyint(1) unsigned NOT NULL default '0',
251
252 PRIMARY KEY rev_page_id (rev_page, rev_id),
253 UNIQUE INDEX rev_id (rev_id),
254 INDEX rev_timestamp (rev_timestamp),
255 INDEX page_timestamp (rev_page,rev_timestamp),
256 INDEX user_timestamp (rev_user,rev_timestamp),
257 INDEX usertext_timestamp (rev_user_text,rev_timestamp)
258
259 ) TYPE=InnoDB;
260
261
262 --
263 -- Holds text of individual page revisions.
264 --
265 -- Field names are a holdover from the 'old' revisions table in
266 -- MediaWiki 1.4 and earlier: an upgrade will transform that
267 -- table into the 'text' table to minimize unnecessary churning
268 -- and downtime. If upgrading, the other fields will be left unused.
269 --
270 CREATE TABLE /*$wgDBprefix*/text (
271 -- Unique text storage key number.
272 -- Note that the 'oldid' parameter used in URLs does *not*
273 -- refer to this number anymore, but to rev_id.
274 --
275 -- revision.rev_text_id is a key to this column
276 old_id int(8) unsigned NOT NULL auto_increment,
277
278 -- Depending on the contents of the old_flags field, the text
279 -- may be convenient plain text, or it may be funkily encoded.
280 old_text mediumblob NOT NULL default '',
281
282 -- Comma-separated list of flags:
283 -- gzip: text is compressed with PHP's gzdeflate() function.
284 -- utf8: text was stored as UTF-8.
285 -- If $wgLegacyEncoding option is on, rows *without* this flag
286 -- will be converted to UTF-8 transparently at load time.
287 -- object: text field contained a serialized PHP object.
288 -- The object either contains multiple versions compressed
289 -- together to achieve a better compression ratio, or it refers
290 -- to another row where the text can be found.
291 old_flags tinyblob NOT NULL default '',
292
293 PRIMARY KEY old_id (old_id)
294
295 ) TYPE=InnoDB;
296
297 --
298 -- Holding area for deleted articles, which may be viewed
299 -- or restored by admins through the Special:Undelete interface.
300 -- The fields generally correspond to the page, revision, and text
301 -- fields, with several caveats.
302 --
303 CREATE TABLE /*$wgDBprefix*/archive (
304 ar_namespace int NOT NULL default '0',
305 ar_title varchar(255) binary NOT NULL default '',
306
307 -- Newly deleted pages will not store text in this table,
308 -- but will reference the separately existing text rows.
309 -- This field is retained for backwards compatibility,
310 -- so old archived pages will remain accessible after
311 -- upgrading from 1.4 to 1.5.
312 -- Text may be gzipped or otherwise funky.
313 ar_text mediumblob NOT NULL default '',
314
315 -- Basic revision stuff...
316 ar_comment tinyblob NOT NULL default '',
317 ar_user int(5) unsigned NOT NULL default '0',
318 ar_user_text varchar(255) binary NOT NULL,
319 ar_timestamp char(14) binary NOT NULL default '',
320 ar_minor_edit tinyint(1) NOT NULL default '0',
321
322 -- See ar_text note.
323 ar_flags tinyblob NOT NULL default '',
324
325 -- When revisions are deleted, their unique rev_id is stored
326 -- here so it can be retained after undeletion. This is necessary
327 -- to retain permalinks to given revisions after accidental delete
328 -- cycles or messy operations like history merges.
329 --
330 -- Old entries from 1.4 will be NULL here, and a new rev_id will
331 -- be created on undeletion for those revisions.
332 ar_rev_id int(8) unsigned,
333
334 -- For newly deleted revisions, this is the text.old_id key to the
335 -- actual stored text. To avoid breaking the block-compression scheme
336 -- and otherwise making storage changes harder, the actual text is
337 -- *not* deleted from the text table, merely hidden by removal of the
338 -- page and revision entries.
339 --
340 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
341 -- ar_text and ar_flags fields will be used to create a new text
342 -- row upon undeletion.
343 ar_text_id int(8) unsigned,
344
345 KEY name_title_timestamp (ar_namespace,ar_title,ar_timestamp)
346
347 ) TYPE=InnoDB;
348
349
350 --
351 -- Track page-to-page hyperlinks within the wiki.
352 --
353 CREATE TABLE /*$wgDBprefix*/pagelinks (
354 -- Key to the page_id of the page containing the link.
355 pl_from int(8) unsigned NOT NULL default '0',
356
357 -- Key to page_namespace/page_title of the target page.
358 -- The target page may or may not exist, and due to renames
359 -- and deletions may refer to different page records as time
360 -- goes by.
361 pl_namespace int NOT NULL default '0',
362 pl_title varchar(255) binary NOT NULL default '',
363
364 UNIQUE KEY pl_from(pl_from,pl_namespace,pl_title),
365 KEY (pl_namespace,pl_title)
366
367 ) TYPE=InnoDB;
368
369
370 --
371 -- Track links to images *used inline*
372 -- We don't distinguish live from broken links here, so
373 -- they do not need to be changed on upload/removal.
374 --
375 CREATE TABLE /*$wgDBprefix*/imagelinks (
376 -- Key to page_id of the page containing the image / media link.
377 il_from int(8) unsigned NOT NULL default '0',
378
379 -- Filename of target image.
380 -- This is also the page_title of the file's description page;
381 -- all such pages are in namespace 6 (NS_IMAGE).
382 il_to varchar(255) binary NOT NULL default '',
383
384 UNIQUE KEY il_from(il_from,il_to),
385 KEY (il_to)
386
387 ) TYPE=InnoDB;
388
389 --
390 -- Track category inclusions *used inline*
391 -- This tracks a single level of category membership
392 -- (folksonomic tagging, really).
393 --
394 CREATE TABLE /*$wgDBprefix*/categorylinks (
395 -- Key to page_id of the page defined as a category member.
396 cl_from int(8) unsigned NOT NULL default '0',
397
398 -- Name of the category.
399 -- This is also the page_title of the category's description page;
400 -- all such pages are in namespace 14 (NS_CATEGORY).
401 cl_to varchar(255) binary NOT NULL default '',
402
403 -- The title of the linking page, or an optional override
404 -- to determine sort order. Sorting is by binary order, which
405 -- isn't always ideal, but collations seem to be an exciting
406 -- and dangerous new world in MySQL...
407 --
408 -- For MySQL 4.1+ with charset set to utf8, the sort key *index*
409 -- needs cut to be smaller than 1024 bytes (at 3 bytes per char).
410 -- To sort properly on the shorter key, this field needs to be
411 -- the same shortness.
412 cl_sortkey varchar(86) binary NOT NULL default '',
413
414 -- This isn't really used at present. Provided for an optional
415 -- sorting method by approximate addition time.
416 cl_timestamp timestamp NOT NULL,
417
418 UNIQUE KEY cl_from(cl_from,cl_to),
419
420 -- We always sort within a given category...
421 KEY cl_sortkey(cl_to,cl_sortkey),
422
423 -- Not really used?
424 KEY cl_timestamp(cl_to,cl_timestamp)
425
426 ) TYPE=InnoDB;
427
428 --
429 -- Contains a single row with some aggregate info
430 -- on the state of the site.
431 --
432 CREATE TABLE /*$wgDBprefix*/site_stats (
433 -- The single row should contain 1 here.
434 ss_row_id int(8) unsigned NOT NULL,
435
436 -- Total number of page views, if hit counters are enabled.
437 ss_total_views bigint(20) unsigned default '0',
438
439 -- Total number of edits performed.
440 ss_total_edits bigint(20) unsigned default '0',
441
442 -- An approximate count of pages matching the following criteria:
443 -- * in namespace 0
444 -- * not a redirect
445 -- * contains the text '[['
446 -- See Article::isCountable() in includes/Article.php
447 ss_good_articles bigint(20) unsigned default '0',
448
449 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
450 ss_total_pages bigint(20) default '-1',
451
452 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
453 ss_users bigint(20) default '-1',
454
455 -- Deprecated, no longer updated as of 1.5
456 ss_admins int(10) default '-1',
457
458 UNIQUE KEY ss_row_id (ss_row_id)
459
460 ) TYPE=InnoDB;
461
462 --
463 -- Stores an ID for every time any article is visited;
464 -- depending on $wgHitcounterUpdateFreq, it is
465 -- periodically cleared and the page_counter column
466 -- in the page table updated for the all articles
467 -- that have been visited.)
468 --
469 CREATE TABLE /*$wgDBprefix*/hitcounter (
470 hc_id INTEGER UNSIGNED NOT NULL
471 ) TYPE=HEAP MAX_ROWS=25000;
472
473
474 --
475 -- The internet is full of jerks, alas. Sometimes it's handy
476 -- to block a vandal or troll account.
477 --
478 CREATE TABLE /*$wgDBprefix*/ipblocks (
479 -- Primary key, introduced for privacy.
480 ipb_id int(8) NOT NULL auto_increment,
481
482 -- Blocked IP address in dotted-quad form or user name.
483 ipb_address varchar(40) binary NOT NULL default '',
484
485 -- Blocked user ID or 0 for IP blocks.
486 ipb_user int(8) unsigned NOT NULL default '0',
487
488 -- User ID who made the block.
489 ipb_by int(8) unsigned NOT NULL default '0',
490
491 -- Text comment made by blocker.
492 ipb_reason tinyblob NOT NULL default '',
493
494 -- Creation (or refresh) date in standard YMDHMS form.
495 -- IP blocks expire automatically.
496 ipb_timestamp char(14) binary NOT NULL default '',
497
498 -- Indicates that the IP address was banned because a banned
499 -- user accessed a page through it. If this is 1, ipb_address
500 -- will be hidden, and the block identified by block ID number.
501 ipb_auto tinyint(1) NOT NULL default '0',
502
503 -- Time at which the block will expire.
504 ipb_expiry char(14) binary NOT NULL default '',
505
506 -- Start and end of an address range, in hexadecimal
507 -- Size chosen to allow IPv6
508 ipb_range_start varchar(32) NOT NULL default '',
509 ipb_range_end varchar(32) NOT NULL default '',
510
511 PRIMARY KEY ipb_id (ipb_id),
512 INDEX ipb_address (ipb_address),
513 INDEX ipb_user (ipb_user),
514 INDEX ipb_range (ipb_range_start(8), ipb_range_end(8))
515
516 ) TYPE=InnoDB;
517
518
519 --
520 -- Uploaded images and other files.
521 --
522 CREATE TABLE /*$wgDBprefix*/image (
523 -- Filename.
524 -- This is also the title of the associated description page,
525 -- which will be in namespace 6 (NS_IMAGE).
526 img_name varchar(255) binary NOT NULL default '',
527
528 -- File size in bytes.
529 img_size int(8) unsigned NOT NULL default '0',
530
531 -- For images, size in pixels.
532 img_width int(5) NOT NULL default '0',
533 img_height int(5) NOT NULL default '0',
534
535 -- Extracted EXIF metadata stored as a serialized PHP array.
536 img_metadata mediumblob NOT NULL,
537
538 -- For images, bits per pixel if known.
539 img_bits int(3) NOT NULL default '0',
540
541 -- Media type as defined by the MEDIATYPE_xxx constants
542 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
543
544 -- major part of a MIME media type as defined by IANA
545 -- see http://www.iana.org/assignments/media-types/
546 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
547
548 -- minor part of a MIME media type as defined by IANA
549 -- the minor parts are not required to adher to any standard
550 -- but should be consistent throughout the database
551 -- see http://www.iana.org/assignments/media-types/
552 img_minor_mime varchar(32) NOT NULL default "unknown",
553
554 -- Description field as entered by the uploader.
555 -- This is displayed in image upload history and logs.
556 img_description tinyblob NOT NULL default '',
557
558 -- user_id and user_name of uploader.
559 img_user int(5) unsigned NOT NULL default '0',
560 img_user_text varchar(255) binary NOT NULL default '',
561
562 -- Time of the upload.
563 img_timestamp char(14) binary NOT NULL default '',
564
565 PRIMARY KEY img_name (img_name),
566
567 -- Used by Special:Imagelist for sort-by-size
568 INDEX img_size (img_size),
569
570 -- Used by Special:Newimages and Special:Imagelist
571 INDEX img_timestamp (img_timestamp)
572
573 ) TYPE=InnoDB;
574
575 --
576 -- Previous revisions of uploaded files.
577 -- Awkwardly, image rows have to be moved into
578 -- this table at re-upload time.
579 --
580 CREATE TABLE /*$wgDBprefix*/oldimage (
581 -- Base filename: key to image.img_name
582 oi_name varchar(255) binary NOT NULL default '',
583
584 -- Filename of the archived file.
585 -- This is generally a timestamp and '!' prepended to the base name.
586 oi_archive_name varchar(255) binary NOT NULL default '',
587
588 -- Other fields as in image...
589 oi_size int(8) unsigned NOT NULL default 0,
590 oi_width int(5) NOT NULL default 0,
591 oi_height int(5) NOT NULL default 0,
592 oi_bits int(3) NOT NULL default 0,
593 oi_description tinyblob NOT NULL default '',
594 oi_user int(5) unsigned NOT NULL default '0',
595 oi_user_text varchar(255) binary NOT NULL default '',
596 oi_timestamp char(14) binary NOT NULL default '',
597
598 INDEX oi_name (oi_name(10))
599
600 ) TYPE=InnoDB;
601
602
603 --
604 -- Primarily a summary table for Special:Recentchanges,
605 -- this table contains some additional info on edits from
606 -- the last few days, see Article::editUpdates()
607 --
608 CREATE TABLE /*$wgDBprefix*/recentchanges (
609 rc_id int(8) NOT NULL auto_increment,
610 rc_timestamp varchar(14) binary NOT NULL default '',
611 rc_cur_time varchar(14) binary NOT NULL default '',
612
613 -- As in revision
614 rc_user int(10) unsigned NOT NULL default '0',
615 rc_user_text varchar(255) binary NOT NULL default '',
616
617 -- When pages are renamed, their RC entries do _not_ change.
618 rc_namespace int NOT NULL default '0',
619 rc_title varchar(255) binary NOT NULL default '',
620
621 -- as in revision...
622 rc_comment varchar(255) binary NOT NULL default '',
623 rc_minor tinyint(3) unsigned NOT NULL default '0',
624
625 -- Edits by user accounts with the 'bot' rights key are
626 -- marked with a 1 here, and will be hidden from the
627 -- default view.
628 rc_bot tinyint(3) unsigned NOT NULL default '0',
629
630 rc_new tinyint(3) unsigned NOT NULL default '0',
631
632 -- Key to page_id (was cur_id prior to 1.5).
633 -- This will keep links working after moves while
634 -- retaining the at-the-time name in the changes list.
635 rc_cur_id int(10) unsigned NOT NULL default '0',
636
637 -- rev_id of the given revision
638 rc_this_oldid int(10) unsigned NOT NULL default '0',
639
640 -- rev_id of the prior revision, for generating diff links.
641 rc_last_oldid int(10) unsigned NOT NULL default '0',
642
643 -- These may no longer be used, with the new move log.
644 rc_type tinyint(3) unsigned NOT NULL default '0',
645 rc_moved_to_ns tinyint(3) unsigned NOT NULL default '0',
646 rc_moved_to_title varchar(255) binary NOT NULL default '',
647
648 -- If the Recent Changes Patrol option is enabled,
649 -- users may mark edits as having been reviewed to
650 -- remove a warning flag on the RC list.
651 -- A value of 1 indicates the page has been reviewed.
652 rc_patrolled tinyint(3) unsigned NOT NULL default '0',
653
654 -- Recorded IP address the edit was made from, if the
655 -- $wgPutIPinRC option is enabled.
656 rc_ip char(15) NOT NULL default '',
657
658 PRIMARY KEY rc_id (rc_id),
659 INDEX rc_timestamp (rc_timestamp),
660 INDEX rc_namespace_title (rc_namespace, rc_title),
661 INDEX rc_cur_id (rc_cur_id),
662 INDEX new_name_timestamp(rc_new,rc_namespace,rc_timestamp),
663 INDEX rc_ip (rc_ip)
664
665 ) TYPE=InnoDB;
666
667 CREATE TABLE /*$wgDBprefix*/watchlist (
668 -- Key to user.user_id
669 wl_user int(5) unsigned NOT NULL,
670
671 -- Key to page_namespace/page_title
672 -- Note that users may watch pages which do not exist yet,
673 -- or existed in the past but have been deleted.
674 wl_namespace int NOT NULL default '0',
675 wl_title varchar(255) binary NOT NULL default '',
676
677 -- Timestamp when user was last sent a notification e-mail;
678 -- cleared when the user visits the page.
679 wl_notificationtimestamp varchar(14) binary,
680
681 UNIQUE KEY (wl_user, wl_namespace, wl_title),
682 KEY namespace_title (wl_namespace,wl_title)
683
684 ) TYPE=InnoDB;
685
686
687 --
688 -- Used by the math module to keep track
689 -- of previously-rendered items.
690 --
691 CREATE TABLE /*$wgDBprefix*/math (
692 -- Binary MD5 hash of the latex fragment, used as an identifier key.
693 math_inputhash varchar(16) NOT NULL,
694
695 -- Not sure what this is, exactly...
696 math_outputhash varchar(16) NOT NULL,
697
698 -- texvc reports how well it thinks the HTML conversion worked;
699 -- if it's a low level the PNG rendering may be preferred.
700 math_html_conservativeness tinyint(1) NOT NULL,
701
702 -- HTML output from texvc, if any
703 math_html text,
704
705 -- MathML output from texvc, if any
706 math_mathml text,
707
708 UNIQUE KEY math_inputhash (math_inputhash)
709
710 ) TYPE=InnoDB;
711
712 --
713 -- When using the default MySQL search backend, page titles
714 -- and text are munged to strip markup, do Unicode case folding,
715 -- and prepare the result for MySQL's fulltext index.
716 --
717 -- This table must be MyISAM; InnoDB does not support the needed
718 -- fulltext index.
719 --
720 CREATE TABLE /*$wgDBprefix*/searchindex (
721 -- Key to page_id
722 si_page int(8) unsigned NOT NULL,
723
724 -- Munged version of title
725 si_title varchar(255) NOT NULL default '',
726
727 -- Munged version of body text
728 si_text mediumtext NOT NULL default '',
729
730 UNIQUE KEY (si_page),
731 FULLTEXT si_title (si_title),
732 FULLTEXT si_text (si_text)
733
734 ) TYPE=MyISAM;
735
736 --
737 -- Recognized interwiki link prefixes
738 --
739 CREATE TABLE /*$wgDBprefix*/interwiki (
740 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
741 iw_prefix char(32) NOT NULL,
742
743 -- The URL of the wiki, with "$1" as a placeholder for an article name.
744 -- Any spaces in the name will be transformed to underscores before
745 -- insertion.
746 iw_url char(127) NOT NULL,
747
748 -- A boolean value indicating whether the wiki is in this project
749 -- (used, for example, to detect redirect loops)
750 iw_local BOOL NOT NULL,
751
752 -- Boolean value indicating whether interwiki transclusions are allowed.
753 iw_trans TINYINT(1) NOT NULL DEFAULT 0,
754
755 UNIQUE KEY iw_prefix (iw_prefix)
756
757 ) TYPE=InnoDB;
758
759 --
760 -- Used for caching expensive grouped queries
761 --
762 CREATE TABLE /*$wgDBprefix*/querycache (
763 -- A key name, generally the base name of of the special page.
764 qc_type char(32) NOT NULL,
765
766 -- Some sort of stored value. Sizes, counts...
767 qc_value int(5) unsigned NOT NULL default '0',
768
769 -- Target namespace+title
770 qc_namespace int NOT NULL default '0',
771 qc_title char(255) binary NOT NULL default '',
772
773 KEY (qc_type,qc_value)
774
775 ) TYPE=InnoDB;
776
777 --
778 -- For a few generic cache operations if not using Memcached
779 --
780 CREATE TABLE /*$wgDBprefix*/objectcache (
781 keyname char(255) binary not null default '',
782 value mediumblob,
783 exptime datetime,
784 unique key (keyname),
785 key (exptime)
786
787 ) TYPE=InnoDB;
788
789 -- For article validation
790 CREATE TABLE /*$wgDBprefix*/validate (
791 val_user int(11) NOT NULL default '0',
792 val_page int(11) unsigned NOT NULL default '0',
793 val_revision int(11) unsigned NOT NULL default '0',
794 val_type int(11) unsigned NOT NULL default '0',
795 val_value int(11) default '0',
796 val_comment varchar(255) NOT NULL default '',
797 val_ip varchar(20) NOT NULL default '',
798 KEY val_user (val_user,val_revision)
799 ) TYPE=InnoDB;
800
801
802 CREATE TABLE /*$wgDBprefix*/logging (
803 -- Symbolic keys for the general log type and the action type
804 -- within the log. The output format will be controlled by the
805 -- action field, but only the type controls categorization.
806 log_type char(10) NOT NULL default '',
807 log_action char(10) NOT NULL default '',
808
809 -- Timestamp. Duh.
810 log_timestamp char(14) NOT NULL default '19700101000000',
811
812 -- The user who performed this action; key to user_id
813 log_user int unsigned NOT NULL default 0,
814
815 -- Key to the page affected. Where a user is the target,
816 -- this will point to the user page.
817 log_namespace int NOT NULL default 0,
818 log_title varchar(255) binary NOT NULL default '',
819
820 -- Freeform text. Interpreted as edit history comments.
821 log_comment varchar(255) NOT NULL default '',
822
823 -- LF separated list of miscellaneous parameters
824 log_params blob NOT NULL default '',
825
826 KEY type_time (log_type, log_timestamp),
827 KEY user_time (log_user, log_timestamp),
828 KEY page_time (log_namespace, log_title, log_timestamp),
829 KEY times (log_timestamp)
830
831 ) TYPE=InnoDB;
832
833 CREATE TABLE /*$wgDBprefix*/trackbacks (
834 tb_id integer AUTO_INCREMENT PRIMARY KEY,
835 tb_page integer REFERENCES page(page_id) ON DELETE CASCADE,
836 tb_title varchar(255) NOT NULL,
837 tb_url varchar(255) NOT NULL,
838 tb_ex text,
839 tb_name varchar(255),
840
841 INDEX (tb_page)
842 );