1e04c9b4c4b8a4890ddeecd9465f24858fbf7b1f
[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 -- This is a shared schema file used for both MySQL and SQLite installs.
6
7 --
8 -- General notes:
9 --
10 -- If possible, create tables as InnoDB to benefit from the
11 -- superior resiliency against crashes and ability to read
12 -- during writes (and write during reads!)
13 --
14 -- Only the 'searchindex' table requires MyISAM due to the
15 -- requirement for fulltext index support, which is missing
16 -- from InnoDB.
17 --
18 --
19 -- The MySQL table backend for MediaWiki currently uses
20 -- 14-character BINARY or VARBINARY fields to store timestamps.
21 -- The format is YYYYMMDDHHMMSS, which is derived from the
22 -- text format of MySQL's TIMESTAMP fields.
23 --
24 -- Historically TIMESTAMP fields were used, but abandoned
25 -- in early 2002 after a lot of trouble with the fields
26 -- auto-updating.
27 --
28 -- The Postgres backend uses DATETIME fields for timestamps,
29 -- and we will migrate the MySQL definitions at some point as
30 -- well.
31 --
32 --
33 -- The /*_*/ comments in this and other files are
34 -- replaced with the defined table prefix by the installer
35 -- and updater scripts. If you are installing or running
36 -- updates manually, you will need to manually insert the
37 -- table prefix if any when running these scripts.
38 --
39
40
41 --
42 -- The user table contains basic account information,
43 -- authentication keys, etc.
44 --
45 -- Some multi-wiki sites may share a single central user table
46 -- between separate wikis using the $wgSharedDB setting.
47 --
48 -- Note that when a external authentication plugin is used,
49 -- user table entries still need to be created to store
50 -- preferences and to key tracking information in the other
51 -- tables.
52 --
53 CREATE TABLE /*_*/user (
54 user_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
55
56 -- Usernames must be unique, must not be in the form of
57 -- an IP address. _Shouldn't_ allow slashes or case
58 -- conflicts. Spaces are allowed, and are _not_ converted
59 -- to underscores like titles. See the User::newFromName() for
60 -- the specific tests that usernames have to pass.
61 user_name varchar(255) binary NOT NULL default '',
62
63 -- Optional 'real name' to be displayed in credit listings
64 user_real_name varchar(255) binary NOT NULL default '',
65
66 -- Password hashes, normally hashed like so:
67 -- MD5(CONCAT(user_id,'-',MD5(plaintext_password))), see
68 -- wfEncryptPassword() in GlobalFunctions.php
69 user_password tinyblob NOT NULL,
70
71 -- When using 'mail me a new password', a random
72 -- password is generated and the hash stored here.
73 -- The previous password is left in place until
74 -- someone actually logs in with the new password,
75 -- at which point the hash is moved to user_password
76 -- and the old password is invalidated.
77 user_newpassword tinyblob NOT NULL,
78
79 -- Timestamp of the last time when a new password was
80 -- sent, for throttling purposes
81 user_newpass_time binary(14),
82
83 -- Note: email should be restricted, not public info.
84 -- Same with passwords.
85 user_email tinytext NOT NULL,
86
87 -- Newline-separated list of name=value defining the user
88 -- preferences
89 -- Now obsolete in favour of user_properties table;
90 -- old values will be migrated from here transparently.
91 user_options blob NOT NULL,
92
93 -- This is a timestamp which is updated when a user
94 -- logs in, logs out, changes preferences, or performs
95 -- some other action requiring HTML cache invalidation
96 -- to ensure that the UI is updated.
97 user_touched binary(14) NOT NULL default '',
98
99 -- A pseudorandomly generated value that is stored in
100 -- a cookie when the "remember password" feature is
101 -- used (previously, a hash of the password was used, but
102 -- this was vulnerable to cookie-stealing attacks)
103 user_token binary(32) NOT NULL default '',
104
105 -- Initially NULL; when a user's e-mail address has been
106 -- validated by returning with a mailed token, this is
107 -- set to the current timestamp.
108 user_email_authenticated binary(14),
109
110 -- Randomly generated token created when the e-mail address
111 -- is set and a confirmation test mail sent.
112 user_email_token binary(32),
113
114 -- Expiration date for the user_email_token
115 user_email_token_expires binary(14),
116
117 -- Timestamp of account registration.
118 -- Accounts predating this schema addition may contain NULL.
119 user_registration binary(14),
120
121 -- Count of edits and edit-like actions.
122 --
123 -- *NOT* intended to be an accurate copy of COUNT(*) WHERE rev_user=user_id
124 -- May contain NULL for old accounts if batch-update scripts haven't been
125 -- run, as well as listing deleted edits and other myriad ways it could be
126 -- out of sync.
127 --
128 -- Meant primarily for heuristic checks to give an impression of whether
129 -- the account has been used much.
130 --
131 user_editcount int
132 ) /*$wgDBTableOptions*/;
133
134 CREATE UNIQUE INDEX /*i*/user_name ON /*_*/user (user_name);
135 CREATE INDEX /*i*/user_email_token ON /*_*/user (user_email_token);
136
137
138 --
139 -- User permissions have been broken out to a separate table;
140 -- this allows sites with a shared user table to have different
141 -- permissions assigned to a user in each project.
142 --
143 -- This table replaces the old user_rights field which used a
144 -- comma-separated blob.
145 --
146 CREATE TABLE /*_*/user_groups (
147 -- Key to user_id
148 ug_user int unsigned NOT NULL default 0,
149
150 -- Group names are short symbolic string keys.
151 -- The set of group names is open-ended, though in practice
152 -- only some predefined ones are likely to be used.
153 --
154 -- At runtime $wgGroupPermissions will associate group keys
155 -- with particular permissions. A user will have the combined
156 -- permissions of any group they're explicitly in, plus
157 -- the implicit '*' and 'user' groups.
158 ug_group varbinary(16) NOT NULL default ''
159 ) /*$wgDBTableOptions*/;
160
161 CREATE UNIQUE INDEX /*i*/ug_user_group ON /*_*/user_groups (ug_user,ug_group);
162 CREATE INDEX /*i*/ug_group ON /*_*/user_groups (ug_group);
163
164
165 --
166 -- Stores notifications of user talk page changes, for the display
167 -- of the "you have new messages" box
168 --
169 CREATE TABLE /*_*/user_newtalk (
170 -- Key to user.user_id
171 user_id int NOT NULL default 0,
172 -- If the user is an anonymous user their IP address is stored here
173 -- since the user_id of 0 is ambiguous
174 user_ip varbinary(40) NOT NULL default '',
175 -- The highest timestamp of revisions of the talk page viewed
176 -- by this user
177 user_last_timestamp binary(14) NOT NULL default ''
178 ) /*$wgDBTableOptions*/;
179
180 -- Indexes renamed for SQLite in 1.14
181 CREATE INDEX /*i*/un_user_id ON /*_*/user_newtalk (user_id);
182 CREATE INDEX /*i*/un_user_ip ON /*_*/user_newtalk (user_ip);
183
184
185 --
186 -- User preferences and perhaps other fun stuff. :)
187 -- Replaces the old user.user_options blob, with a couple nice properties:
188 --
189 -- 1) We only store non-default settings, so changes to the defauls
190 -- are now reflected for everybody, not just new accounts.
191 -- 2) We can more easily do bulk lookups, statistics, or modifications of
192 -- saved options since it's a sane table structure.
193 --
194 CREATE TABLE /*_*/user_properties (
195 -- Foreign key to user.user_id
196 up_user int NOT NULL,
197
198 -- Name of the option being saved. This is indexed for bulk lookup.
199 up_property varbinary(32) NOT NULL,
200
201 -- Property value as a string.
202 up_value blob
203 ) /*$wgDBTableOptions*/;
204
205 CREATE UNIQUE INDEX /*i*/user_properties_user_property ON /*_*/user_properties (up_user,up_property);
206 CREATE INDEX /*i*/user_properties_property ON /*_*/user_properties (up_property);
207
208 --
209 -- Core of the wiki: each page has an entry here which identifies
210 -- it by title and contains some essential metadata.
211 --
212 CREATE TABLE /*_*/page (
213 -- Unique identifier number. The page_id will be preserved across
214 -- edits and rename operations, but not deletions and recreations.
215 page_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
216
217 -- A page name is broken into a namespace and a title.
218 -- The namespace keys are UI-language-independent constants,
219 -- defined in includes/Defines.php
220 page_namespace int NOT NULL,
221
222 -- The rest of the title, as text.
223 -- Spaces are transformed into underscores in title storage.
224 page_title varchar(255) binary NOT NULL,
225
226 -- Comma-separated set of permission keys indicating who
227 -- can move or edit the page.
228 page_restrictions tinyblob NOT NULL,
229
230 -- Number of times this page has been viewed.
231 page_counter bigint unsigned NOT NULL default 0,
232
233 -- 1 indicates the article is a redirect.
234 page_is_redirect tinyint unsigned NOT NULL default 0,
235
236 -- 1 indicates this is a new entry, with only one edit.
237 -- Not all pages with one edit are new pages.
238 page_is_new tinyint unsigned NOT NULL default 0,
239
240 -- Random value between 0 and 1, used for Special:Randompage
241 page_random real unsigned NOT NULL,
242
243 -- This timestamp is updated whenever the page changes in
244 -- a way requiring it to be re-rendered, invalidating caches.
245 -- Aside from editing this includes permission changes,
246 -- creation or deletion of linked pages, and alteration
247 -- of contained templates.
248 page_touched binary(14) NOT NULL default '',
249
250 -- Handy key to revision.rev_id of the current revision.
251 -- This may be 0 during page creation, but that shouldn't
252 -- happen outside of a transaction... hopefully.
253 page_latest int unsigned NOT NULL,
254
255 -- Uncompressed length in bytes of the page's current source text.
256 page_len int unsigned NOT NULL
257 ) /*$wgDBTableOptions*/;
258
259 CREATE UNIQUE INDEX /*i*/name_title ON /*_*/page (page_namespace,page_title);
260 CREATE INDEX /*i*/page_random ON /*_*/page (page_random);
261 CREATE INDEX /*i*/page_len ON /*_*/page (page_len);
262
263
264 --
265 -- Every edit of a page creates also a revision row.
266 -- This stores metadata about the revision, and a reference
267 -- to the text storage backend.
268 --
269 CREATE TABLE /*_*/revision (
270 rev_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
271
272 -- Key to page_id. This should _never_ be invalid.
273 rev_page int unsigned NOT NULL,
274
275 -- Key to text.old_id, where the actual bulk text is stored.
276 -- It's possible for multiple revisions to use the same text,
277 -- for instance revisions where only metadata is altered
278 -- or a rollback to a previous version.
279 rev_text_id int unsigned NOT NULL,
280
281 -- Text comment summarizing the change.
282 -- This text is shown in the history and other changes lists,
283 -- rendered in a subset of wiki markup by Linker::formatComment()
284 rev_comment tinyblob NOT NULL,
285
286 -- Key to user.user_id of the user who made this edit.
287 -- Stores 0 for anonymous edits and for some mass imports.
288 rev_user int unsigned NOT NULL default 0,
289
290 -- Text username or IP address of the editor.
291 rev_user_text varchar(255) binary NOT NULL default '',
292
293 -- Timestamp
294 rev_timestamp binary(14) NOT NULL default '',
295
296 -- Records whether the user marked the 'minor edit' checkbox.
297 -- Many automated edits are marked as minor.
298 rev_minor_edit tinyint unsigned NOT NULL default 0,
299
300 -- Not yet used; reserved for future changes to the deletion system.
301 rev_deleted tinyint unsigned NOT NULL default 0,
302
303 -- Length of this revision in bytes
304 rev_len int unsigned,
305
306 -- Key to revision.rev_id
307 -- This field is used to add support for a tree structure (The Adjacency List Model)
308 rev_parent_id int unsigned default NULL
309
310 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
311 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
312
313 CREATE UNIQUE INDEX /*i*/rev_page_id ON /*_*/revision (rev_page, rev_id);
314 CREATE INDEX /*i*/rev_timestamp ON /*_*/revision (rev_timestamp);
315 CREATE INDEX /*i*/page_timestamp ON /*_*/revision (rev_page,rev_timestamp);
316 CREATE INDEX /*i*/user_timestamp ON /*_*/revision (rev_user,rev_timestamp);
317 CREATE INDEX /*i*/usertext_timestamp ON /*_*/revision (rev_user_text,rev_timestamp);
318
319 --
320 -- Holds text of individual page revisions.
321 --
322 -- Field names are a holdover from the 'old' revisions table in
323 -- MediaWiki 1.4 and earlier: an upgrade will transform that
324 -- table into the 'text' table to minimize unnecessary churning
325 -- and downtime. If upgrading, the other fields will be left unused.
326 --
327 CREATE TABLE /*_*/text (
328 -- Unique text storage key number.
329 -- Note that the 'oldid' parameter used in URLs does *not*
330 -- refer to this number anymore, but to rev_id.
331 --
332 -- revision.rev_text_id is a key to this column
333 old_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
334
335 -- Depending on the contents of the old_flags field, the text
336 -- may be convenient plain text, or it may be funkily encoded.
337 old_text mediumblob NOT NULL,
338
339 -- Comma-separated list of flags:
340 -- gzip: text is compressed with PHP's gzdeflate() function.
341 -- utf8: text was stored as UTF-8.
342 -- If $wgLegacyEncoding option is on, rows *without* this flag
343 -- will be converted to UTF-8 transparently at load time.
344 -- object: text field contained a serialized PHP object.
345 -- The object either contains multiple versions compressed
346 -- together to achieve a better compression ratio, or it refers
347 -- to another row where the text can be found.
348 old_flags tinyblob NOT NULL
349 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=10240;
350 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
351
352
353 --
354 -- Holding area for deleted articles, which may be viewed
355 -- or restored by admins through the Special:Undelete interface.
356 -- The fields generally correspond to the page, revision, and text
357 -- fields, with several caveats.
358 --
359 CREATE TABLE /*_*/archive (
360 ar_namespace int NOT NULL default 0,
361 ar_title varchar(255) binary NOT NULL default '',
362
363 -- Newly deleted pages will not store text in this table,
364 -- but will reference the separately existing text rows.
365 -- This field is retained for backwards compatibility,
366 -- so old archived pages will remain accessible after
367 -- upgrading from 1.4 to 1.5.
368 -- Text may be gzipped or otherwise funky.
369 ar_text mediumblob NOT NULL,
370
371 -- Basic revision stuff...
372 ar_comment tinyblob NOT NULL,
373 ar_user int unsigned NOT NULL default 0,
374 ar_user_text varchar(255) binary NOT NULL,
375 ar_timestamp binary(14) NOT NULL default '',
376 ar_minor_edit tinyint NOT NULL default 0,
377
378 -- See ar_text note.
379 ar_flags tinyblob NOT NULL,
380
381 -- When revisions are deleted, their unique rev_id is stored
382 -- here so it can be retained after undeletion. This is necessary
383 -- to retain permalinks to given revisions after accidental delete
384 -- cycles or messy operations like history merges.
385 --
386 -- Old entries from 1.4 will be NULL here, and a new rev_id will
387 -- be created on undeletion for those revisions.
388 ar_rev_id int unsigned,
389
390 -- For newly deleted revisions, this is the text.old_id key to the
391 -- actual stored text. To avoid breaking the block-compression scheme
392 -- and otherwise making storage changes harder, the actual text is
393 -- *not* deleted from the text table, merely hidden by removal of the
394 -- page and revision entries.
395 --
396 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
397 -- ar_text and ar_flags fields will be used to create a new text
398 -- row upon undeletion.
399 ar_text_id int unsigned,
400
401 -- rev_deleted for archives
402 ar_deleted tinyint unsigned NOT NULL default 0,
403
404 -- Length of this revision in bytes
405 ar_len int unsigned,
406
407 -- Reference to page_id. Useful for sysadmin fixing of large pages
408 -- merged together in the archives, or for cleanly restoring a page
409 -- at its original ID number if possible.
410 --
411 -- Will be NULL for pages deleted prior to 1.11.
412 ar_page_id int unsigned,
413
414 -- Original previous revision
415 ar_parent_id int unsigned default NULL
416 ) /*$wgDBTableOptions*/;
417
418 CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp);
419 CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp);
420 CREATE INDEX /*i*/ar_page_revid ON /*_*/archive (ar_namespace, ar_title, ar_rev_id);
421
422
423 --
424 -- Track page-to-page hyperlinks within the wiki.
425 --
426 CREATE TABLE /*_*/pagelinks (
427 -- Key to the page_id of the page containing the link.
428 pl_from int unsigned NOT NULL default 0,
429
430 -- Key to page_namespace/page_title of the target page.
431 -- The target page may or may not exist, and due to renames
432 -- and deletions may refer to different page records as time
433 -- goes by.
434 pl_namespace int NOT NULL default 0,
435 pl_title varchar(255) binary NOT NULL default ''
436 ) /*$wgDBTableOptions*/;
437
438 CREATE UNIQUE INDEX /*i*/pl_from ON /*_*/pagelinks (pl_from,pl_namespace,pl_title);
439 CREATE UNIQUE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from);
440
441
442 --
443 -- Track template inclusions.
444 --
445 CREATE TABLE /*_*/templatelinks (
446 -- Key to the page_id of the page containing the link.
447 tl_from int unsigned NOT NULL default 0,
448
449 -- Key to page_namespace/page_title of the target page.
450 -- The target page may or may not exist, and due to renames
451 -- and deletions may refer to different page records as time
452 -- goes by.
453 tl_namespace int NOT NULL default 0,
454 tl_title varchar(255) binary NOT NULL default ''
455 ) /*$wgDBTableOptions*/;
456
457 CREATE UNIQUE INDEX /*i*/tl_from ON /*_*/templatelinks (tl_from,tl_namespace,tl_title);
458 CREATE UNIQUE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from);
459
460
461 --
462 -- Track links to images *used inline*
463 -- We don't distinguish live from broken links here, so
464 -- they do not need to be changed on upload/removal.
465 --
466 CREATE TABLE /*_*/imagelinks (
467 -- Key to page_id of the page containing the image / media link.
468 il_from int unsigned NOT NULL default 0,
469
470 -- Filename of target image.
471 -- This is also the page_title of the file's description page;
472 -- all such pages are in namespace 6 (NS_FILE).
473 il_to varchar(255) binary NOT NULL default ''
474 ) /*$wgDBTableOptions*/;
475
476 CREATE UNIQUE INDEX /*i*/il_from ON /*_*/imagelinks (il_from,il_to);
477 CREATE UNIQUE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from);
478
479
480 --
481 -- Track category inclusions *used inline*
482 -- This tracks a single level of category membership
483 --
484 CREATE TABLE /*_*/categorylinks (
485 -- Key to page_id of the page defined as a category member.
486 cl_from int unsigned NOT NULL default 0,
487
488 -- Name of the category.
489 -- This is also the page_title of the category's description page;
490 -- all such pages are in namespace 14 (NS_CATEGORY).
491 cl_to varchar(255) binary NOT NULL default '',
492
493 -- The title of the linking page, or an optional override
494 -- to determine sort order. Sorting is by binary order, which
495 -- isn't always ideal, but collations seem to be an exciting
496 -- and dangerous new world in MySQL... The sortkey is updated
497 -- if no override exists and cl_from is renamed.
498 --
499 -- Truncate so that the cl_sortkey key fits in 1000 bytes
500 -- (MyISAM 5 with server_character_set=utf8)
501 cl_sortkey varchar(70) binary NOT NULL default '',
502
503 -- This isn't really used at present. Provided for an optional
504 -- sorting method by approximate addition time.
505 cl_timestamp timestamp NOT NULL
506 ) /*$wgDBTableOptions*/;
507
508 CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to);
509
510 -- We always sort within a given category...
511 CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_sortkey,cl_from);
512
513 -- Not really used?
514 CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);
515
516
517 --
518 -- Track all existing categories. Something is a category if 1) it has an en-
519 -- try somewhere in categorylinks, or 2) it once did. Categories might not
520 -- have corresponding pages, so they need to be tracked separately.
521 --
522 CREATE TABLE /*_*/category (
523 -- Primary key
524 cat_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
525
526 -- Name of the category, in the same form as page_title (with underscores).
527 -- If there is a category page corresponding to this category, by definition,
528 -- it has this name (in the Category namespace).
529 cat_title varchar(255) binary NOT NULL,
530
531 -- The numbers of member pages (including categories and media), subcatego-
532 -- ries, and Image: namespace members, respectively. These are signed to
533 -- make underflow more obvious. We make the first number include the second
534 -- two for better sorting: subtracting for display is easy, adding for order-
535 -- ing is not.
536 cat_pages int signed NOT NULL default 0,
537 cat_subcats int signed NOT NULL default 0,
538 cat_files int signed NOT NULL default 0,
539
540 -- Reserved for future use
541 cat_hidden tinyint unsigned NOT NULL default 0
542 ) /*$wgDBTableOptions*/;
543
544 CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);
545
546 -- For Special:Mostlinkedcategories
547 CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);
548
549
550 --
551 -- Track links to external URLs
552 --
553 CREATE TABLE /*_*/externallinks (
554 -- page_id of the referring page
555 el_from int unsigned NOT NULL default 0,
556
557 -- The URL
558 el_to blob NOT NULL,
559
560 -- In the case of HTTP URLs, this is the URL with any username or password
561 -- removed, and with the labels in the hostname reversed and converted to
562 -- lower case. An extra dot is added to allow for matching of either
563 -- example.com or *.example.com in a single scan.
564 -- Example:
565 -- http://user:password@sub.example.com/page.html
566 -- becomes
567 -- http://com.example.sub./page.html
568 -- which allows for fast searching for all pages under example.com with the
569 -- clause:
570 -- WHERE el_index LIKE 'http://com.example.%'
571 el_index blob NOT NULL
572 ) /*$wgDBTableOptions*/;
573
574 CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from, el_to(40));
575 CREATE INDEX /*i*/el_to ON /*_*/externallinks (el_to(60), el_from);
576 CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index(60));
577
578
579 --
580 -- Track external user accounts, if ExternalAuth is used
581 --
582 CREATE TABLE /*_*/external_user (
583 -- Foreign key to user_id
584 eu_local_id int unsigned NOT NULL PRIMARY KEY,
585
586 -- Some opaque identifier provided by the external database
587 eu_external_id varchar(255) binary NOT NULL
588 ) /*$wgDBTableOptions*/;
589
590 CREATE UNIQUE INDEX /*i*/eu_external_id ON /*_*/external_user (eu_external_id);
591
592
593 --
594 -- Track interlanguage links
595 --
596 CREATE TABLE /*_*/langlinks (
597 -- page_id of the referring page
598 ll_from int unsigned NOT NULL default 0,
599
600 -- Language code of the target
601 ll_lang varbinary(20) NOT NULL default '',
602
603 -- Title of the target, including namespace
604 ll_title varchar(255) binary NOT NULL default ''
605 ) /*$wgDBTableOptions*/;
606
607 CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang);
608 CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);
609
610
611 --
612 -- Track inline interwiki links
613 --
614 CREATE TABLE /*_*/iwlinks (
615 -- page_id of the referring page
616 iwl_from int unsigned NOT NULL default 0,
617
618 -- Interwiki prefix code of the target
619 iwl_prefix varbinary(20) NOT NULL default '',
620
621 -- Title of the target, including namespace
622 iwl_title varchar(255) binary NOT NULL default ''
623 ) /*$wgDBTableOptions*/;
624
625 CREATE UNIQUE INDEX /*i*/iwl_from ON /*_*/iwlinks (iwl_from, iwl_prefix, iwl_title);
626 CREATE UNIQUE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from);
627
628
629 --
630 -- Contains a single row with some aggregate info
631 -- on the state of the site.
632 --
633 CREATE TABLE /*_*/site_stats (
634 -- The single row should contain 1 here.
635 ss_row_id int unsigned NOT NULL,
636
637 -- Total number of page views, if hit counters are enabled.
638 ss_total_views bigint unsigned default 0,
639
640 -- Total number of edits performed.
641 ss_total_edits bigint unsigned default 0,
642
643 -- An approximate count of pages matching the following criteria:
644 -- * in namespace 0
645 -- * not a redirect
646 -- * contains the text '[['
647 -- See Article::isCountable() in includes/Article.php
648 ss_good_articles bigint unsigned default 0,
649
650 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
651 ss_total_pages bigint default '-1',
652
653 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
654 ss_users bigint default '-1',
655
656 -- Number of users that still edit
657 ss_active_users bigint default '-1',
658
659 -- Deprecated, no longer updated as of 1.5
660 ss_admins int default '-1',
661
662 -- Number of images, equivalent to SELECT COUNT(*) FROM image
663 ss_images int default 0
664 ) /*$wgDBTableOptions*/;
665
666 -- Pointless index to assuage developer superstitions
667 CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id);
668
669
670 --
671 -- Stores an ID for every time any article is visited;
672 -- depending on $wgHitcounterUpdateFreq, it is
673 -- periodically cleared and the page_counter column
674 -- in the page table updated for all the articles
675 -- that have been visited.)
676 --
677 CREATE TABLE /*_*/hitcounter (
678 hc_id int unsigned NOT NULL
679 ) ENGINE=HEAP MAX_ROWS=25000;
680
681
682 --
683 -- The internet is full of jerks, alas. Sometimes it's handy
684 -- to block a vandal or troll account.
685 --
686 CREATE TABLE /*_*/ipblocks (
687 -- Primary key, introduced for privacy.
688 ipb_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
689
690 -- Blocked IP address in dotted-quad form or user name.
691 ipb_address tinyblob NOT NULL,
692
693 -- Blocked user ID or 0 for IP blocks.
694 ipb_user int unsigned NOT NULL default 0,
695
696 -- User ID who made the block.
697 ipb_by int unsigned NOT NULL default 0,
698
699 -- User name of blocker
700 ipb_by_text varchar(255) binary NOT NULL default '',
701
702 -- Text comment made by blocker.
703 ipb_reason tinyblob NOT NULL,
704
705 -- Creation (or refresh) date in standard YMDHMS form.
706 -- IP blocks expire automatically.
707 ipb_timestamp binary(14) NOT NULL default '',
708
709 -- Indicates that the IP address was banned because a banned
710 -- user accessed a page through it. If this is 1, ipb_address
711 -- will be hidden, and the block identified by block ID number.
712 ipb_auto bool NOT NULL default 0,
713
714 -- If set to 1, block applies only to logged-out users
715 ipb_anon_only bool NOT NULL default 0,
716
717 -- Block prevents account creation from matching IP addresses
718 ipb_create_account bool NOT NULL default 1,
719
720 -- Block triggers autoblocks
721 ipb_enable_autoblock bool NOT NULL default '1',
722
723 -- Time at which the block will expire.
724 -- May be "infinity"
725 ipb_expiry varbinary(14) NOT NULL default '',
726
727 -- Start and end of an address range, in hexadecimal
728 -- Size chosen to allow IPv6
729 ipb_range_start tinyblob NOT NULL,
730 ipb_range_end tinyblob NOT NULL,
731
732 -- Flag for entries hidden from users and Sysops
733 ipb_deleted bool NOT NULL default 0,
734
735 -- Block prevents user from accessing Special:Emailuser
736 ipb_block_email bool NOT NULL default 0,
737
738 -- Block allows user to edit their own talk page
739 ipb_allow_usertalk bool NOT NULL default 0
740
741 ) /*$wgDBTableOptions*/;
742
743 -- Unique index to support "user already blocked" messages
744 -- Any new options which prevent collisions should be included
745 CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only);
746
747 CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
748 CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start(8), ipb_range_end(8));
749 CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
750 CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
751
752
753 --
754 -- Uploaded images and other files.
755 --
756 CREATE TABLE /*_*/image (
757 -- Filename.
758 -- This is also the title of the associated description page,
759 -- which will be in namespace 6 (NS_FILE).
760 img_name varchar(255) binary NOT NULL default '' PRIMARY KEY,
761
762 -- File size in bytes.
763 img_size int unsigned NOT NULL default 0,
764
765 -- For images, size in pixels.
766 img_width int NOT NULL default 0,
767 img_height int NOT NULL default 0,
768
769 -- Extracted EXIF metadata stored as a serialized PHP array.
770 img_metadata mediumblob NOT NULL,
771
772 -- For images, bits per pixel if known.
773 img_bits int NOT NULL default 0,
774
775 -- Media type as defined by the MEDIATYPE_xxx constants
776 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
777
778 -- major part of a MIME media type as defined by IANA
779 -- see http://www.iana.org/assignments/media-types/
780 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
781
782 -- minor part of a MIME media type as defined by IANA
783 -- the minor parts are not required to adher to any standard
784 -- but should be consistent throughout the database
785 -- see http://www.iana.org/assignments/media-types/
786 img_minor_mime varbinary(100) NOT NULL default "unknown",
787
788 -- Description field as entered by the uploader.
789 -- This is displayed in image upload history and logs.
790 img_description tinyblob NOT NULL,
791
792 -- user_id and user_name of uploader.
793 img_user int unsigned NOT NULL default 0,
794 img_user_text varchar(255) binary NOT NULL,
795
796 -- Time of the upload.
797 img_timestamp varbinary(14) NOT NULL default '',
798
799 -- SHA-1 content hash in base-36
800 img_sha1 varbinary(32) NOT NULL default ''
801 ) /*$wgDBTableOptions*/;
802
803 CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
804 -- Used by Special:ListFiles for sort-by-size
805 CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
806 -- Used by Special:Newimages and Special:ListFiles
807 CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
808 -- Used in API and duplicate search
809 CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1);
810
811
812 --
813 -- Previous revisions of uploaded files.
814 -- Awkwardly, image rows have to be moved into
815 -- this table at re-upload time.
816 --
817 CREATE TABLE /*_*/oldimage (
818 -- Base filename: key to image.img_name
819 oi_name varchar(255) binary NOT NULL default '',
820
821 -- Filename of the archived file.
822 -- This is generally a timestamp and '!' prepended to the base name.
823 oi_archive_name varchar(255) binary NOT NULL default '',
824
825 -- Other fields as in image...
826 oi_size int unsigned NOT NULL default 0,
827 oi_width int NOT NULL default 0,
828 oi_height int NOT NULL default 0,
829 oi_bits int NOT NULL default 0,
830 oi_description tinyblob NOT NULL,
831 oi_user int unsigned NOT NULL default 0,
832 oi_user_text varchar(255) binary NOT NULL,
833 oi_timestamp binary(14) NOT NULL default '',
834
835 oi_metadata mediumblob NOT NULL,
836 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
837 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
838 oi_minor_mime varbinary(100) NOT NULL default "unknown",
839 oi_deleted tinyint unsigned NOT NULL default 0,
840 oi_sha1 varbinary(32) NOT NULL default ''
841 ) /*$wgDBTableOptions*/;
842
843 CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
844 CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
845 -- oi_archive_name truncated to 14 to avoid key length overflow
846 CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name(14));
847 CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1);
848
849
850 --
851 -- Record of deleted file data
852 --
853 CREATE TABLE /*_*/filearchive (
854 -- Unique row id
855 fa_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
856
857 -- Original base filename; key to image.img_name, page.page_title, etc
858 fa_name varchar(255) binary NOT NULL default '',
859
860 -- Filename of archived file, if an old revision
861 fa_archive_name varchar(255) binary default '',
862
863 -- Which storage bin (directory tree or object store) the file data
864 -- is stored in. Should be 'deleted' for files that have been deleted;
865 -- any other bin is not yet in use.
866 fa_storage_group varbinary(16),
867
868 -- SHA-1 of the file contents plus extension, used as a key for storage.
869 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
870 --
871 -- If NULL, the file was missing at deletion time or has been purged
872 -- from the archival storage.
873 fa_storage_key varbinary(64) default '',
874
875 -- Deletion information, if this file is deleted.
876 fa_deleted_user int,
877 fa_deleted_timestamp binary(14) default '',
878 fa_deleted_reason text,
879
880 -- Duped fields from image
881 fa_size int unsigned default 0,
882 fa_width int default 0,
883 fa_height int default 0,
884 fa_metadata mediumblob,
885 fa_bits int default 0,
886 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
887 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
888 fa_minor_mime varbinary(100) default "unknown",
889 fa_description tinyblob,
890 fa_user int unsigned default 0,
891 fa_user_text varchar(255) binary,
892 fa_timestamp binary(14) default '',
893
894 -- Visibility of deleted revisions, bitfield
895 fa_deleted tinyint unsigned NOT NULL default 0
896 ) /*$wgDBTableOptions*/;
897
898 -- pick out by image name
899 CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
900 -- pick out dupe files
901 CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
902 -- sort by deletion time
903 CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
904 -- sort by uploader
905 CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
906
907
908 --
909 -- Primarily a summary table for Special:Recentchanges,
910 -- this table contains some additional info on edits from
911 -- the last few days, see Article::editUpdates()
912 --
913 CREATE TABLE /*_*/recentchanges (
914 rc_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
915 rc_timestamp varbinary(14) NOT NULL default '',
916 rc_cur_time varbinary(14) NOT NULL default '',
917
918 -- As in revision
919 rc_user int unsigned NOT NULL default 0,
920 rc_user_text varchar(255) binary NOT NULL,
921
922 -- When pages are renamed, their RC entries do _not_ change.
923 rc_namespace int NOT NULL default 0,
924 rc_title varchar(255) binary NOT NULL default '',
925
926 -- as in revision...
927 rc_comment varchar(255) binary NOT NULL default '',
928 rc_minor tinyint unsigned NOT NULL default 0,
929
930 -- Edits by user accounts with the 'bot' rights key are
931 -- marked with a 1 here, and will be hidden from the
932 -- default view.
933 rc_bot tinyint unsigned NOT NULL default 0,
934
935 rc_new tinyint unsigned NOT NULL default 0,
936
937 -- Key to page_id (was cur_id prior to 1.5).
938 -- This will keep links working after moves while
939 -- retaining the at-the-time name in the changes list.
940 rc_cur_id int unsigned NOT NULL default 0,
941
942 -- rev_id of the given revision
943 rc_this_oldid int unsigned NOT NULL default 0,
944
945 -- rev_id of the prior revision, for generating diff links.
946 rc_last_oldid int unsigned NOT NULL default 0,
947
948 -- These may no longer be used, with the new move log.
949 rc_type tinyint unsigned NOT NULL default 0,
950 rc_moved_to_ns tinyint unsigned NOT NULL default 0,
951 rc_moved_to_title varchar(255) binary NOT NULL default '',
952
953 -- If the Recent Changes Patrol option is enabled,
954 -- users may mark edits as having been reviewed to
955 -- remove a warning flag on the RC list.
956 -- A value of 1 indicates the page has been reviewed.
957 rc_patrolled tinyint unsigned NOT NULL default 0,
958
959 -- Recorded IP address the edit was made from, if the
960 -- $wgPutIPinRC option is enabled.
961 rc_ip varbinary(40) NOT NULL default '',
962
963 -- Text length in characters before
964 -- and after the edit
965 rc_old_len int,
966 rc_new_len int,
967
968 -- Visibility of recent changes items, bitfield
969 rc_deleted tinyint unsigned NOT NULL default 0,
970
971 -- Value corresonding to log_id, specific log entries
972 rc_logid int unsigned NOT NULL default 0,
973 -- Store log type info here, or null
974 rc_log_type varbinary(255) NULL default NULL,
975 -- Store log action or null
976 rc_log_action varbinary(255) NULL default NULL,
977 -- Log params
978 rc_params blob NULL
979 ) /*$wgDBTableOptions*/;
980
981 CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
982 CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
983 CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
984 CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
985 CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
986 CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
987 CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);
988
989
990 CREATE TABLE /*_*/watchlist (
991 -- Key to user.user_id
992 wl_user int unsigned NOT NULL,
993
994 -- Key to page_namespace/page_title
995 -- Note that users may watch pages which do not exist yet,
996 -- or existed in the past but have been deleted.
997 wl_namespace int NOT NULL default 0,
998 wl_title varchar(255) binary NOT NULL default '',
999
1000 -- Timestamp when user was last sent a notification e-mail;
1001 -- cleared when the user visits the page.
1002 wl_notificationtimestamp varbinary(14)
1003
1004 ) /*$wgDBTableOptions*/;
1005
1006 CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
1007 CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);
1008
1009
1010 --
1011 -- Used by the math module to keep track
1012 -- of previously-rendered items.
1013 --
1014 CREATE TABLE /*_*/math (
1015 -- Binary MD5 hash of the latex fragment, used as an identifier key.
1016 math_inputhash varbinary(16) NOT NULL,
1017
1018 -- Not sure what this is, exactly...
1019 math_outputhash varbinary(16) NOT NULL,
1020
1021 -- texvc reports how well it thinks the HTML conversion worked;
1022 -- if it's a low level the PNG rendering may be preferred.
1023 math_html_conservativeness tinyint NOT NULL,
1024
1025 -- HTML output from texvc, if any
1026 math_html text,
1027
1028 -- MathML output from texvc, if any
1029 math_mathml text
1030 ) /*$wgDBTableOptions*/;
1031
1032 CREATE UNIQUE INDEX /*i*/math_inputhash ON /*_*/math (math_inputhash);
1033
1034
1035 --
1036 -- When using the default MySQL search backend, page titles
1037 -- and text are munged to strip markup, do Unicode case folding,
1038 -- and prepare the result for MySQL's fulltext index.
1039 --
1040 -- This table must be MyISAM; InnoDB does not support the needed
1041 -- fulltext index.
1042 --
1043 CREATE TABLE /*_*/searchindex (
1044 -- Key to page_id
1045 si_page int unsigned NOT NULL,
1046
1047 -- Munged version of title
1048 si_title varchar(255) NOT NULL default '',
1049
1050 -- Munged version of body text
1051 si_text mediumtext NOT NULL
1052 ) ENGINE=MyISAM;
1053
1054 CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
1055 CREATE FULLTEXT INDEX /*i*/si_title ON /*_*/searchindex (si_title);
1056 CREATE FULLTEXT INDEX /*i*/si_text ON /*_*/searchindex (si_text);
1057
1058
1059 --
1060 -- Recognized interwiki link prefixes
1061 --
1062 CREATE TABLE /*_*/interwiki (
1063 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
1064 iw_prefix varchar(32) NOT NULL,
1065
1066 -- The URL of the wiki, with "$1" as a placeholder for an article name.
1067 -- Any spaces in the name will be transformed to underscores before
1068 -- insertion.
1069 iw_url blob NOT NULL,
1070
1071 -- The URL of the file api.php
1072 iw_api blob NOT NULL,
1073
1074 -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' ))
1075 iw_wikiid varchar(64) NOT NULL,
1076
1077 -- A boolean value indicating whether the wiki is in this project
1078 -- (used, for example, to detect redirect loops)
1079 iw_local bool NOT NULL,
1080
1081 -- Boolean value indicating whether interwiki transclusions are allowed.
1082 iw_trans tinyint NOT NULL default 0
1083 ) /*$wgDBTableOptions*/;
1084
1085 CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);
1086
1087
1088 --
1089 -- Used for caching expensive grouped queries
1090 --
1091 CREATE TABLE /*_*/querycache (
1092 -- A key name, generally the base name of of the special page.
1093 qc_type varbinary(32) NOT NULL,
1094
1095 -- Some sort of stored value. Sizes, counts...
1096 qc_value int unsigned NOT NULL default 0,
1097
1098 -- Target namespace+title
1099 qc_namespace int NOT NULL default 0,
1100 qc_title varchar(255) binary NOT NULL default ''
1101 ) /*$wgDBTableOptions*/;
1102
1103 CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);
1104
1105
1106 --
1107 -- For a few generic cache operations if not using Memcached
1108 --
1109 CREATE TABLE /*_*/objectcache (
1110 keyname varbinary(255) NOT NULL default '' PRIMARY KEY,
1111 value mediumblob,
1112 exptime datetime
1113 ) /*$wgDBTableOptions*/;
1114 CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);
1115
1116
1117 --
1118 -- Cache of interwiki transclusion
1119 --
1120 CREATE TABLE /*_*/transcache (
1121 tc_url varbinary(255) NOT NULL,
1122 tc_contents text,
1123 tc_time binary(14) NOT NULL
1124 ) /*$wgDBTableOptions*/;
1125
1126 CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url);
1127
1128
1129 CREATE TABLE /*_*/logging (
1130 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1131 log_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1132
1133 -- Symbolic keys for the general log type and the action type
1134 -- within the log. The output format will be controlled by the
1135 -- action field, but only the type controls categorization.
1136 log_type varbinary(32) NOT NULL default '',
1137 log_action varbinary(32) NOT NULL default '',
1138
1139 -- Timestamp. Duh.
1140 log_timestamp binary(14) NOT NULL default '19700101000000',
1141
1142 -- The user who performed this action; key to user_id
1143 log_user int unsigned NOT NULL default 0,
1144
1145 -- Name of the user who performed this action
1146 log_user_text varchar(255) binary NOT NULL default '',
1147
1148 -- Key to the page affected. Where a user is the target,
1149 -- this will point to the user page.
1150 log_namespace int NOT NULL default 0,
1151 log_title varchar(255) binary NOT NULL default '',
1152 log_page int unsigned NULL,
1153
1154 -- Freeform text. Interpreted as edit history comments.
1155 log_comment varchar(255) NOT NULL default '',
1156
1157 -- LF separated list of miscellaneous parameters
1158 log_params blob NOT NULL,
1159
1160 -- rev_deleted for logs
1161 log_deleted tinyint unsigned NOT NULL default 0
1162 ) /*$wgDBTableOptions*/;
1163
1164 CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
1165 CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
1166 CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
1167 CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
1168 CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp);
1169 CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp);
1170
1171
1172 CREATE TABLE /*_*/log_search (
1173 -- The type of ID (rev ID, log ID, rev timestamp, username)
1174 ls_field varbinary(32) NOT NULL,
1175 -- The value of the ID
1176 ls_value varchar(255) NOT NULL,
1177 -- Key to log_id
1178 ls_log_id int unsigned NOT NULL default 0
1179 ) /*$wgDBTableOptions*/;
1180 CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id);
1181 CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);
1182
1183
1184 CREATE TABLE /*_*/trackbacks (
1185 tb_id int PRIMARY KEY AUTO_INCREMENT,
1186 tb_page int REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
1187 tb_title varchar(255) NOT NULL,
1188 tb_url blob NOT NULL,
1189 tb_ex text,
1190 tb_name varchar(255)
1191 ) /*$wgDBTableOptions*/;
1192 CREATE INDEX /*i*/tb_page ON /*_*/trackbacks (tb_page);
1193
1194
1195 -- Jobs performed by parallel apache threads or a command-line daemon
1196 CREATE TABLE /*_*/job (
1197 job_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1198
1199 -- Command name
1200 -- Limited to 60 to prevent key length overflow
1201 job_cmd varbinary(60) NOT NULL default '',
1202
1203 -- Namespace and title to act on
1204 -- Should be 0 and '' if the command does not operate on a title
1205 job_namespace int NOT NULL,
1206 job_title varchar(255) binary NOT NULL,
1207
1208 -- Any other parameters to the command
1209 -- Stored as a PHP serialized array, or an empty string if there are no parameters
1210 job_params blob NOT NULL
1211 ) /*$wgDBTableOptions*/;
1212
1213 CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title, job_params(128));
1214
1215
1216 -- Details of updates to cached special pages
1217 CREATE TABLE /*_*/querycache_info (
1218 -- Special page name
1219 -- Corresponds to a qc_type value
1220 qci_type varbinary(32) NOT NULL default '',
1221
1222 -- Timestamp of last update
1223 qci_timestamp binary(14) NOT NULL default '19700101000000'
1224 ) /*$wgDBTableOptions*/;
1225
1226 CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type);
1227
1228
1229 -- For each redirect, this table contains exactly one row defining its target
1230 CREATE TABLE /*_*/redirect (
1231 -- Key to the page_id of the redirect page
1232 rd_from int unsigned NOT NULL default 0 PRIMARY KEY,
1233
1234 -- Key to page_namespace/page_title of the target page.
1235 -- The target page may or may not exist, and due to renames
1236 -- and deletions may refer to different page records as time
1237 -- goes by.
1238 rd_namespace int NOT NULL default 0,
1239 rd_title varchar(255) binary NOT NULL default '',
1240 rd_interwiki varchar(32) default NULL,
1241 rd_fragment varchar(255) binary default NULL
1242 ) /*$wgDBTableOptions*/;
1243
1244 CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);
1245
1246
1247 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1248 CREATE TABLE /*_*/querycachetwo (
1249 -- A key name, generally the base name of of the special page.
1250 qcc_type varbinary(32) NOT NULL,
1251
1252 -- Some sort of stored value. Sizes, counts...
1253 qcc_value int unsigned NOT NULL default 0,
1254
1255 -- Target namespace+title
1256 qcc_namespace int NOT NULL default 0,
1257 qcc_title varchar(255) binary NOT NULL default '',
1258
1259 -- Target namespace+title2
1260 qcc_namespacetwo int NOT NULL default 0,
1261 qcc_titletwo varchar(255) binary NOT NULL default ''
1262 ) /*$wgDBTableOptions*/;
1263
1264 CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
1265 CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
1266 CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
1267
1268
1269 -- Used for storing page restrictions (i.e. protection levels)
1270 CREATE TABLE /*_*/page_restrictions (
1271 -- Page to apply restrictions to (Foreign Key to page).
1272 pr_page int NOT NULL,
1273 -- The protection type (edit, move, etc)
1274 pr_type varbinary(60) NOT NULL,
1275 -- The protection level (Sysop, autoconfirmed, etc)
1276 pr_level varbinary(60) NOT NULL,
1277 -- Whether or not to cascade the protection down to pages transcluded.
1278 pr_cascade tinyint NOT NULL,
1279 -- Field for future support of per-user restriction.
1280 pr_user int NULL,
1281 -- Field for time-limited protection.
1282 pr_expiry varbinary(14) NULL,
1283 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1284 pr_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT
1285 ) /*$wgDBTableOptions*/;
1286
1287 CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
1288 CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
1289 CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
1290 CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);
1291
1292
1293 -- Protected titles - nonexistent pages that have been protected
1294 CREATE TABLE /*_*/protected_titles (
1295 pt_namespace int NOT NULL,
1296 pt_title varchar(255) binary NOT NULL,
1297 pt_user int unsigned NOT NULL,
1298 pt_reason tinyblob,
1299 pt_timestamp binary(14) NOT NULL,
1300 pt_expiry varbinary(14) NOT NULL default '',
1301 pt_create_perm varbinary(60) NOT NULL
1302 ) /*$wgDBTableOptions*/;
1303
1304 CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
1305 CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);
1306
1307
1308 -- Name/value pairs indexed by page_id
1309 CREATE TABLE /*_*/page_props (
1310 pp_page int NOT NULL,
1311 pp_propname varbinary(60) NOT NULL,
1312 pp_value blob NOT NULL
1313 ) /*$wgDBTableOptions*/;
1314
1315 CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
1316
1317
1318 -- A table to log updates, one text key row per update.
1319 CREATE TABLE /*_*/updatelog (
1320 ul_key varchar(255) NOT NULL PRIMARY KEY,
1321 ul_value blob
1322 ) /*$wgDBTableOptions*/;
1323
1324
1325 -- A table to track tags for revisions, logs and recent changes.
1326 CREATE TABLE /*_*/change_tag (
1327 -- RCID for the change
1328 ct_rc_id int NULL,
1329 -- LOGID for the change
1330 ct_log_id int NULL,
1331 -- REVID for the change
1332 ct_rev_id int NULL,
1333 -- Tag applied
1334 ct_tag varchar(255) NOT NULL,
1335 -- Parameters for the tag, presently unused
1336 ct_params blob NULL
1337 ) /*$wgDBTableOptions*/;
1338
1339 CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
1340 CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
1341 CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
1342 -- Covering index, so we can pull all the info only out of the index.
1343 CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
1344
1345
1346 -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
1347 -- that only works on MySQL 4.1+
1348 CREATE TABLE /*_*/tag_summary (
1349 -- RCID for the change
1350 ts_rc_id int NULL,
1351 -- LOGID for the change
1352 ts_log_id int NULL,
1353 -- REVID for the change
1354 ts_rev_id int NULL,
1355 -- Comma-separated list of tags
1356 ts_tags blob NOT NULL
1357 ) /*$wgDBTableOptions*/;
1358
1359 CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
1360 CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
1361 CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);
1362
1363
1364 CREATE TABLE /*_*/valid_tag (
1365 vt_tag varchar(255) NOT NULL PRIMARY KEY
1366 ) /*$wgDBTableOptions*/;
1367
1368 -- Table for storing localisation data
1369 CREATE TABLE /*_*/l10n_cache (
1370 -- Language code
1371 lc_lang varbinary(32) NOT NULL,
1372 -- Cache key
1373 lc_key varchar(255) NOT NULL,
1374 -- Value
1375 lc_value mediumblob NOT NULL
1376 ) /*$wgDBTableOptions*/;
1377 CREATE INDEX /*i*/lc_lang_key ON /*_*/l10n_cache (lc_lang, lc_key);
1378
1379 -- vim: sw=2 sts=2 et