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