\n to eof
[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 -- A binary string obtained by applying a sortkey generation algorithm
494 -- (Language::convertToSortkey()) to page_title, or cl_sortkey_prefix . "\0"
495 -- . page_title if cl_sortkey_prefix is nonempty.
496 cl_sortkey varbinary(255) NOT NULL default '',
497
498 -- A prefix for the raw sortkey manually specified by the user, either via
499 -- [[Category:Foo|prefix]] or {{defaultsort:prefix}}. If nonempty, it's
500 -- concatenated with a null followed by the page title before the sortkey
501 -- conversion algorithm is run. We store this so that we can update
502 -- collations without reparsing all pages.
503 cl_sortkey_prefix varchar(255) binary NOT NULL default '',
504
505 -- This isn't really used at present. Provided for an optional
506 -- sorting method by approximate addition time.
507 cl_timestamp timestamp NOT NULL,
508
509 -- Stores $wgCategoryCollation at the time cl_sortkey was generated. This
510 -- can be used to install new collation versions, tracking which rows are not
511 -- yet updated. '' means no collation, this is a legacy row that needs to be
512 -- updated by updateCollation.php. In the future, it might be possible to
513 -- specify different collations per category.
514 cl_collation varbinary(32) NOT NULL default '',
515
516 -- Stores whether cl_from is a category, file, or other page, so we can
517 -- paginate the three categories separately. This never has to be updated
518 -- after the page is created, since none of these page types can be moved to
519 -- any other.
520 cl_type ENUM('page', 'subcat', 'file') NOT NULL default 'page'
521 ) /*$wgDBTableOptions*/;
522
523 CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to);
524
525 -- We always sort within a given category, and within a given type. FIXME:
526 -- Formerly this index didn't cover cl_type (since that didn't exist), so old
527 -- callers won't be using an index: fix this?
528 CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_type,cl_sortkey,cl_from);
529
530 -- Not really used?
531 CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);
532
533 -- For finding rows with outdated collation
534 CREATE INDEX /*i*/cl_collation ON /*_*/categorylinks (cl_collation);
535
536 --
537 -- Track all existing categories. Something is a category if 1) it has an en-
538 -- try somewhere in categorylinks, or 2) it once did. Categories might not
539 -- have corresponding pages, so they need to be tracked separately.
540 --
541 CREATE TABLE /*_*/category (
542 -- Primary key
543 cat_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
544
545 -- Name of the category, in the same form as page_title (with underscores).
546 -- If there is a category page corresponding to this category, by definition,
547 -- it has this name (in the Category namespace).
548 cat_title varchar(255) binary NOT NULL,
549
550 -- The numbers of member pages (including categories and media), subcatego-
551 -- ries, and Image: namespace members, respectively. These are signed to
552 -- make underflow more obvious. We make the first number include the second
553 -- two for better sorting: subtracting for display is easy, adding for order-
554 -- ing is not.
555 cat_pages int signed NOT NULL default 0,
556 cat_subcats int signed NOT NULL default 0,
557 cat_files int signed NOT NULL default 0,
558
559 -- Reserved for future use
560 cat_hidden tinyint unsigned NOT NULL default 0
561 ) /*$wgDBTableOptions*/;
562
563 CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);
564
565 -- For Special:Mostlinkedcategories
566 CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);
567
568
569 --
570 -- Track links to external URLs
571 --
572 CREATE TABLE /*_*/externallinks (
573 -- page_id of the referring page
574 el_from int unsigned NOT NULL default 0,
575
576 -- The URL
577 el_to blob NOT NULL,
578
579 -- In the case of HTTP URLs, this is the URL with any username or password
580 -- removed, and with the labels in the hostname reversed and converted to
581 -- lower case. An extra dot is added to allow for matching of either
582 -- example.com or *.example.com in a single scan.
583 -- Example:
584 -- http://user:password@sub.example.com/page.html
585 -- becomes
586 -- http://com.example.sub./page.html
587 -- which allows for fast searching for all pages under example.com with the
588 -- clause:
589 -- WHERE el_index LIKE 'http://com.example.%'
590 el_index blob NOT NULL
591 ) /*$wgDBTableOptions*/;
592
593 CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from, el_to(40));
594 CREATE INDEX /*i*/el_to ON /*_*/externallinks (el_to(60), el_from);
595 CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index(60));
596
597
598 --
599 -- Track external user accounts, if ExternalAuth is used
600 --
601 CREATE TABLE /*_*/external_user (
602 -- Foreign key to user_id
603 eu_local_id int unsigned NOT NULL PRIMARY KEY,
604
605 -- Some opaque identifier provided by the external database
606 eu_external_id varchar(255) binary NOT NULL
607 ) /*$wgDBTableOptions*/;
608
609 CREATE UNIQUE INDEX /*i*/eu_external_id ON /*_*/external_user (eu_external_id);
610
611
612 --
613 -- Track interlanguage links
614 --
615 CREATE TABLE /*_*/langlinks (
616 -- page_id of the referring page
617 ll_from int unsigned NOT NULL default 0,
618
619 -- Language code of the target
620 ll_lang varbinary(20) NOT NULL default '',
621
622 -- Title of the target, including namespace
623 ll_title varchar(255) binary NOT NULL default ''
624 ) /*$wgDBTableOptions*/;
625
626 CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang);
627 CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);
628
629
630 --
631 -- Track inline interwiki links
632 --
633 CREATE TABLE /*_*/iwlinks (
634 -- page_id of the referring page
635 iwl_from int unsigned NOT NULL default 0,
636
637 -- Interwiki prefix code of the target
638 iwl_prefix varbinary(20) NOT NULL default '',
639
640 -- Title of the target, including namespace
641 iwl_title varchar(255) binary NOT NULL default ''
642 ) /*$wgDBTableOptions*/;
643
644 CREATE UNIQUE INDEX /*i*/iwl_from ON /*_*/iwlinks (iwl_from, iwl_prefix, iwl_title);
645 CREATE UNIQUE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from);
646
647
648 --
649 -- Contains a single row with some aggregate info
650 -- on the state of the site.
651 --
652 CREATE TABLE /*_*/site_stats (
653 -- The single row should contain 1 here.
654 ss_row_id int unsigned NOT NULL,
655
656 -- Total number of page views, if hit counters are enabled.
657 ss_total_views bigint unsigned default 0,
658
659 -- Total number of edits performed.
660 ss_total_edits bigint unsigned default 0,
661
662 -- An approximate count of pages matching the following criteria:
663 -- * in namespace 0
664 -- * not a redirect
665 -- * contains the text '[['
666 -- See Article::isCountable() in includes/Article.php
667 ss_good_articles bigint unsigned default 0,
668
669 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
670 ss_total_pages bigint default '-1',
671
672 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
673 ss_users bigint default '-1',
674
675 -- Number of users that still edit
676 ss_active_users bigint default '-1',
677
678 -- Deprecated, no longer updated as of 1.5
679 ss_admins int default '-1',
680
681 -- Number of images, equivalent to SELECT COUNT(*) FROM image
682 ss_images int default 0
683 ) /*$wgDBTableOptions*/;
684
685 -- Pointless index to assuage developer superstitions
686 CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id);
687
688
689 --
690 -- Stores an ID for every time any article is visited;
691 -- depending on $wgHitcounterUpdateFreq, it is
692 -- periodically cleared and the page_counter column
693 -- in the page table updated for all the articles
694 -- that have been visited.)
695 --
696 CREATE TABLE /*_*/hitcounter (
697 hc_id int unsigned NOT NULL
698 ) ENGINE=HEAP MAX_ROWS=25000;
699
700
701 --
702 -- The internet is full of jerks, alas. Sometimes it's handy
703 -- to block a vandal or troll account.
704 --
705 CREATE TABLE /*_*/ipblocks (
706 -- Primary key, introduced for privacy.
707 ipb_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
708
709 -- Blocked IP address in dotted-quad form or user name.
710 ipb_address tinyblob NOT NULL,
711
712 -- Blocked user ID or 0 for IP blocks.
713 ipb_user int unsigned NOT NULL default 0,
714
715 -- User ID who made the block.
716 ipb_by int unsigned NOT NULL default 0,
717
718 -- User name of blocker
719 ipb_by_text varchar(255) binary NOT NULL default '',
720
721 -- Text comment made by blocker.
722 ipb_reason tinyblob NOT NULL,
723
724 -- Creation (or refresh) date in standard YMDHMS form.
725 -- IP blocks expire automatically.
726 ipb_timestamp binary(14) NOT NULL default '',
727
728 -- Indicates that the IP address was banned because a banned
729 -- user accessed a page through it. If this is 1, ipb_address
730 -- will be hidden, and the block identified by block ID number.
731 ipb_auto bool NOT NULL default 0,
732
733 -- If set to 1, block applies only to logged-out users
734 ipb_anon_only bool NOT NULL default 0,
735
736 -- Block prevents account creation from matching IP addresses
737 ipb_create_account bool NOT NULL default 1,
738
739 -- Block triggers autoblocks
740 ipb_enable_autoblock bool NOT NULL default '1',
741
742 -- Time at which the block will expire.
743 -- May be "infinity"
744 ipb_expiry varbinary(14) NOT NULL default '',
745
746 -- Start and end of an address range, in hexadecimal
747 -- Size chosen to allow IPv6
748 ipb_range_start tinyblob NOT NULL,
749 ipb_range_end tinyblob NOT NULL,
750
751 -- Flag for entries hidden from users and Sysops
752 ipb_deleted bool NOT NULL default 0,
753
754 -- Block prevents user from accessing Special:Emailuser
755 ipb_block_email bool NOT NULL default 0,
756
757 -- Block allows user to edit their own talk page
758 ipb_allow_usertalk bool NOT NULL default 0
759
760 ) /*$wgDBTableOptions*/;
761
762 -- Unique index to support "user already blocked" messages
763 -- Any new options which prevent collisions should be included
764 CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only);
765
766 CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
767 CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start(8), ipb_range_end(8));
768 CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
769 CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
770
771
772 --
773 -- Uploaded images and other files.
774 --
775 CREATE TABLE /*_*/image (
776 -- Filename.
777 -- This is also the title of the associated description page,
778 -- which will be in namespace 6 (NS_FILE).
779 img_name varchar(255) binary NOT NULL default '' PRIMARY KEY,
780
781 -- File size in bytes.
782 img_size int unsigned NOT NULL default 0,
783
784 -- For images, size in pixels.
785 img_width int NOT NULL default 0,
786 img_height int NOT NULL default 0,
787
788 -- Extracted EXIF metadata stored as a serialized PHP array.
789 img_metadata mediumblob NOT NULL,
790
791 -- For images, bits per pixel if known.
792 img_bits int NOT NULL default 0,
793
794 -- Media type as defined by the MEDIATYPE_xxx constants
795 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
796
797 -- major part of a MIME media type as defined by IANA
798 -- see http://www.iana.org/assignments/media-types/
799 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
800
801 -- minor part of a MIME media type as defined by IANA
802 -- the minor parts are not required to adher to any standard
803 -- but should be consistent throughout the database
804 -- see http://www.iana.org/assignments/media-types/
805 img_minor_mime varbinary(100) NOT NULL default "unknown",
806
807 -- Description field as entered by the uploader.
808 -- This is displayed in image upload history and logs.
809 img_description tinyblob NOT NULL,
810
811 -- user_id and user_name of uploader.
812 img_user int unsigned NOT NULL default 0,
813 img_user_text varchar(255) binary NOT NULL,
814
815 -- Time of the upload.
816 img_timestamp varbinary(14) NOT NULL default '',
817
818 -- SHA-1 content hash in base-36
819 img_sha1 varbinary(32) NOT NULL default ''
820 ) /*$wgDBTableOptions*/;
821
822 CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
823 -- Used by Special:ListFiles for sort-by-size
824 CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
825 -- Used by Special:Newimages and Special:ListFiles
826 CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
827 -- Used in API and duplicate search
828 CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1);
829
830
831 --
832 -- Previous revisions of uploaded files.
833 -- Awkwardly, image rows have to be moved into
834 -- this table at re-upload time.
835 --
836 CREATE TABLE /*_*/oldimage (
837 -- Base filename: key to image.img_name
838 oi_name varchar(255) binary NOT NULL default '',
839
840 -- Filename of the archived file.
841 -- This is generally a timestamp and '!' prepended to the base name.
842 oi_archive_name varchar(255) binary NOT NULL default '',
843
844 -- Other fields as in image...
845 oi_size int unsigned NOT NULL default 0,
846 oi_width int NOT NULL default 0,
847 oi_height int NOT NULL default 0,
848 oi_bits int NOT NULL default 0,
849 oi_description tinyblob NOT NULL,
850 oi_user int unsigned NOT NULL default 0,
851 oi_user_text varchar(255) binary NOT NULL,
852 oi_timestamp binary(14) NOT NULL default '',
853
854 oi_metadata mediumblob NOT NULL,
855 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
856 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
857 oi_minor_mime varbinary(100) NOT NULL default "unknown",
858 oi_deleted tinyint unsigned NOT NULL default 0,
859 oi_sha1 varbinary(32) NOT NULL default ''
860 ) /*$wgDBTableOptions*/;
861
862 CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
863 CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
864 -- oi_archive_name truncated to 14 to avoid key length overflow
865 CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name(14));
866 CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1);
867
868
869 --
870 -- Record of deleted file data
871 --
872 CREATE TABLE /*_*/filearchive (
873 -- Unique row id
874 fa_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
875
876 -- Original base filename; key to image.img_name, page.page_title, etc
877 fa_name varchar(255) binary NOT NULL default '',
878
879 -- Filename of archived file, if an old revision
880 fa_archive_name varchar(255) binary default '',
881
882 -- Which storage bin (directory tree or object store) the file data
883 -- is stored in. Should be 'deleted' for files that have been deleted;
884 -- any other bin is not yet in use.
885 fa_storage_group varbinary(16),
886
887 -- SHA-1 of the file contents plus extension, used as a key for storage.
888 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
889 --
890 -- If NULL, the file was missing at deletion time or has been purged
891 -- from the archival storage.
892 fa_storage_key varbinary(64) default '',
893
894 -- Deletion information, if this file is deleted.
895 fa_deleted_user int,
896 fa_deleted_timestamp binary(14) default '',
897 fa_deleted_reason text,
898
899 -- Duped fields from image
900 fa_size int unsigned default 0,
901 fa_width int default 0,
902 fa_height int default 0,
903 fa_metadata mediumblob,
904 fa_bits int default 0,
905 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
906 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
907 fa_minor_mime varbinary(100) default "unknown",
908 fa_description tinyblob,
909 fa_user int unsigned default 0,
910 fa_user_text varchar(255) binary,
911 fa_timestamp binary(14) default '',
912
913 -- Visibility of deleted revisions, bitfield
914 fa_deleted tinyint unsigned NOT NULL default 0
915 ) /*$wgDBTableOptions*/;
916
917 -- pick out by image name
918 CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
919 -- pick out dupe files
920 CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
921 -- sort by deletion time
922 CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
923 -- sort by uploader
924 CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
925
926
927 --
928 -- Primarily a summary table for Special:Recentchanges,
929 -- this table contains some additional info on edits from
930 -- the last few days, see Article::editUpdates()
931 --
932 CREATE TABLE /*_*/recentchanges (
933 rc_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
934 rc_timestamp varbinary(14) NOT NULL default '',
935 rc_cur_time varbinary(14) NOT NULL default '',
936
937 -- As in revision
938 rc_user int unsigned NOT NULL default 0,
939 rc_user_text varchar(255) binary NOT NULL,
940
941 -- When pages are renamed, their RC entries do _not_ change.
942 rc_namespace int NOT NULL default 0,
943 rc_title varchar(255) binary NOT NULL default '',
944
945 -- as in revision...
946 rc_comment varchar(255) binary NOT NULL default '',
947 rc_minor tinyint unsigned NOT NULL default 0,
948
949 -- Edits by user accounts with the 'bot' rights key are
950 -- marked with a 1 here, and will be hidden from the
951 -- default view.
952 rc_bot tinyint unsigned NOT NULL default 0,
953
954 rc_new tinyint unsigned NOT NULL default 0,
955
956 -- Key to page_id (was cur_id prior to 1.5).
957 -- This will keep links working after moves while
958 -- retaining the at-the-time name in the changes list.
959 rc_cur_id int unsigned NOT NULL default 0,
960
961 -- rev_id of the given revision
962 rc_this_oldid int unsigned NOT NULL default 0,
963
964 -- rev_id of the prior revision, for generating diff links.
965 rc_last_oldid int unsigned NOT NULL default 0,
966
967 -- These may no longer be used, with the new move log.
968 rc_type tinyint unsigned NOT NULL default 0,
969 rc_moved_to_ns tinyint unsigned NOT NULL default 0,
970 rc_moved_to_title varchar(255) binary NOT NULL default '',
971
972 -- If the Recent Changes Patrol option is enabled,
973 -- users may mark edits as having been reviewed to
974 -- remove a warning flag on the RC list.
975 -- A value of 1 indicates the page has been reviewed.
976 rc_patrolled tinyint unsigned NOT NULL default 0,
977
978 -- Recorded IP address the edit was made from, if the
979 -- $wgPutIPinRC option is enabled.
980 rc_ip varbinary(40) NOT NULL default '',
981
982 -- Text length in characters before
983 -- and after the edit
984 rc_old_len int,
985 rc_new_len int,
986
987 -- Visibility of recent changes items, bitfield
988 rc_deleted tinyint unsigned NOT NULL default 0,
989
990 -- Value corresonding to log_id, specific log entries
991 rc_logid int unsigned NOT NULL default 0,
992 -- Store log type info here, or null
993 rc_log_type varbinary(255) NULL default NULL,
994 -- Store log action or null
995 rc_log_action varbinary(255) NULL default NULL,
996 -- Log params
997 rc_params blob NULL
998 ) /*$wgDBTableOptions*/;
999
1000 CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
1001 CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
1002 CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
1003 CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
1004 CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
1005 CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
1006 CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);
1007
1008
1009 CREATE TABLE /*_*/watchlist (
1010 -- Key to user.user_id
1011 wl_user int unsigned NOT NULL,
1012
1013 -- Key to page_namespace/page_title
1014 -- Note that users may watch pages which do not exist yet,
1015 -- or existed in the past but have been deleted.
1016 wl_namespace int NOT NULL default 0,
1017 wl_title varchar(255) binary NOT NULL default '',
1018
1019 -- Timestamp when user was last sent a notification e-mail;
1020 -- cleared when the user visits the page.
1021 wl_notificationtimestamp varbinary(14)
1022
1023 ) /*$wgDBTableOptions*/;
1024
1025 CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
1026 CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);
1027
1028
1029 --
1030 -- Used by the math module to keep track
1031 -- of previously-rendered items.
1032 --
1033 CREATE TABLE /*_*/math (
1034 -- Binary MD5 hash of the latex fragment, used as an identifier key.
1035 math_inputhash varbinary(16) NOT NULL,
1036
1037 -- Not sure what this is, exactly...
1038 math_outputhash varbinary(16) NOT NULL,
1039
1040 -- texvc reports how well it thinks the HTML conversion worked;
1041 -- if it's a low level the PNG rendering may be preferred.
1042 math_html_conservativeness tinyint NOT NULL,
1043
1044 -- HTML output from texvc, if any
1045 math_html text,
1046
1047 -- MathML output from texvc, if any
1048 math_mathml text
1049 ) /*$wgDBTableOptions*/;
1050
1051 CREATE UNIQUE INDEX /*i*/math_inputhash ON /*_*/math (math_inputhash);
1052
1053
1054 --
1055 -- When using the default MySQL search backend, page titles
1056 -- and text are munged to strip markup, do Unicode case folding,
1057 -- and prepare the result for MySQL's fulltext index.
1058 --
1059 -- This table must be MyISAM; InnoDB does not support the needed
1060 -- fulltext index.
1061 --
1062 CREATE TABLE /*_*/searchindex (
1063 -- Key to page_id
1064 si_page int unsigned NOT NULL,
1065
1066 -- Munged version of title
1067 si_title varchar(255) NOT NULL default '',
1068
1069 -- Munged version of body text
1070 si_text mediumtext NOT NULL
1071 ) ENGINE=MyISAM;
1072
1073 CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
1074 CREATE FULLTEXT INDEX /*i*/si_title ON /*_*/searchindex (si_title);
1075 CREATE FULLTEXT INDEX /*i*/si_text ON /*_*/searchindex (si_text);
1076
1077
1078 --
1079 -- Recognized interwiki link prefixes
1080 --
1081 CREATE TABLE /*_*/interwiki (
1082 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
1083 iw_prefix varchar(32) NOT NULL,
1084
1085 -- The URL of the wiki, with "$1" as a placeholder for an article name.
1086 -- Any spaces in the name will be transformed to underscores before
1087 -- insertion.
1088 iw_url blob NOT NULL,
1089
1090 -- The URL of the file api.php
1091 iw_api blob NOT NULL,
1092
1093 -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' ))
1094 iw_wikiid varchar(64) NOT NULL,
1095
1096 -- A boolean value indicating whether the wiki is in this project
1097 -- (used, for example, to detect redirect loops)
1098 iw_local bool NOT NULL,
1099
1100 -- Boolean value indicating whether interwiki transclusions are allowed.
1101 iw_trans tinyint NOT NULL default 0
1102 ) /*$wgDBTableOptions*/;
1103
1104 CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);
1105
1106
1107 --
1108 -- Used for caching expensive grouped queries
1109 --
1110 CREATE TABLE /*_*/querycache (
1111 -- A key name, generally the base name of of the special page.
1112 qc_type varbinary(32) NOT NULL,
1113
1114 -- Some sort of stored value. Sizes, counts...
1115 qc_value int unsigned NOT NULL default 0,
1116
1117 -- Target namespace+title
1118 qc_namespace int NOT NULL default 0,
1119 qc_title varchar(255) binary NOT NULL default ''
1120 ) /*$wgDBTableOptions*/;
1121
1122 CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);
1123
1124
1125 --
1126 -- For a few generic cache operations if not using Memcached
1127 --
1128 CREATE TABLE /*_*/objectcache (
1129 keyname varbinary(255) NOT NULL default '' PRIMARY KEY,
1130 value mediumblob,
1131 exptime datetime
1132 ) /*$wgDBTableOptions*/;
1133 CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);
1134
1135
1136 --
1137 -- Cache of interwiki transclusion
1138 --
1139 CREATE TABLE /*_*/transcache (
1140 tc_url varbinary(255) NOT NULL,
1141 tc_contents text,
1142 tc_time binary(14) NOT NULL
1143 ) /*$wgDBTableOptions*/;
1144
1145 CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url);
1146
1147
1148 CREATE TABLE /*_*/logging (
1149 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1150 log_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1151
1152 -- Symbolic keys for the general log type and the action type
1153 -- within the log. The output format will be controlled by the
1154 -- action field, but only the type controls categorization.
1155 log_type varbinary(32) NOT NULL default '',
1156 log_action varbinary(32) NOT NULL default '',
1157
1158 -- Timestamp. Duh.
1159 log_timestamp binary(14) NOT NULL default '19700101000000',
1160
1161 -- The user who performed this action; key to user_id
1162 log_user int unsigned NOT NULL default 0,
1163
1164 -- Name of the user who performed this action
1165 log_user_text varchar(255) binary NOT NULL default '',
1166
1167 -- Key to the page affected. Where a user is the target,
1168 -- this will point to the user page.
1169 log_namespace int NOT NULL default 0,
1170 log_title varchar(255) binary NOT NULL default '',
1171 log_page int unsigned NULL,
1172
1173 -- Freeform text. Interpreted as edit history comments.
1174 log_comment varchar(255) NOT NULL default '',
1175
1176 -- LF separated list of miscellaneous parameters
1177 log_params blob NOT NULL,
1178
1179 -- rev_deleted for logs
1180 log_deleted tinyint unsigned NOT NULL default 0
1181 ) /*$wgDBTableOptions*/;
1182
1183 CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
1184 CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
1185 CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
1186 CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
1187 CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp);
1188 CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp);
1189
1190
1191 CREATE TABLE /*_*/log_search (
1192 -- The type of ID (rev ID, log ID, rev timestamp, username)
1193 ls_field varbinary(32) NOT NULL,
1194 -- The value of the ID
1195 ls_value varchar(255) NOT NULL,
1196 -- Key to log_id
1197 ls_log_id int unsigned NOT NULL default 0
1198 ) /*$wgDBTableOptions*/;
1199 CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id);
1200 CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);
1201
1202
1203 CREATE TABLE /*_*/trackbacks (
1204 tb_id int PRIMARY KEY AUTO_INCREMENT,
1205 tb_page int REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
1206 tb_title varchar(255) NOT NULL,
1207 tb_url blob NOT NULL,
1208 tb_ex text,
1209 tb_name varchar(255)
1210 ) /*$wgDBTableOptions*/;
1211 CREATE INDEX /*i*/tb_page ON /*_*/trackbacks (tb_page);
1212
1213
1214 -- Jobs performed by parallel apache threads or a command-line daemon
1215 CREATE TABLE /*_*/job (
1216 job_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1217
1218 -- Command name
1219 -- Limited to 60 to prevent key length overflow
1220 job_cmd varbinary(60) NOT NULL default '',
1221
1222 -- Namespace and title to act on
1223 -- Should be 0 and '' if the command does not operate on a title
1224 job_namespace int NOT NULL,
1225 job_title varchar(255) binary NOT NULL,
1226
1227 -- Any other parameters to the command
1228 -- Stored as a PHP serialized array, or an empty string if there are no parameters
1229 job_params blob NOT NULL
1230 ) /*$wgDBTableOptions*/;
1231
1232 CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title, job_params(128));
1233
1234
1235 -- Details of updates to cached special pages
1236 CREATE TABLE /*_*/querycache_info (
1237 -- Special page name
1238 -- Corresponds to a qc_type value
1239 qci_type varbinary(32) NOT NULL default '',
1240
1241 -- Timestamp of last update
1242 qci_timestamp binary(14) NOT NULL default '19700101000000'
1243 ) /*$wgDBTableOptions*/;
1244
1245 CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type);
1246
1247
1248 -- For each redirect, this table contains exactly one row defining its target
1249 CREATE TABLE /*_*/redirect (
1250 -- Key to the page_id of the redirect page
1251 rd_from int unsigned NOT NULL default 0 PRIMARY KEY,
1252
1253 -- Key to page_namespace/page_title of the target page.
1254 -- The target page may or may not exist, and due to renames
1255 -- and deletions may refer to different page records as time
1256 -- goes by.
1257 rd_namespace int NOT NULL default 0,
1258 rd_title varchar(255) binary NOT NULL default '',
1259 rd_interwiki varchar(32) default NULL,
1260 rd_fragment varchar(255) binary default NULL
1261 ) /*$wgDBTableOptions*/;
1262
1263 CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);
1264
1265
1266 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1267 CREATE TABLE /*_*/querycachetwo (
1268 -- A key name, generally the base name of of the special page.
1269 qcc_type varbinary(32) NOT NULL,
1270
1271 -- Some sort of stored value. Sizes, counts...
1272 qcc_value int unsigned NOT NULL default 0,
1273
1274 -- Target namespace+title
1275 qcc_namespace int NOT NULL default 0,
1276 qcc_title varchar(255) binary NOT NULL default '',
1277
1278 -- Target namespace+title2
1279 qcc_namespacetwo int NOT NULL default 0,
1280 qcc_titletwo varchar(255) binary NOT NULL default ''
1281 ) /*$wgDBTableOptions*/;
1282
1283 CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
1284 CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
1285 CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
1286
1287
1288 -- Used for storing page restrictions (i.e. protection levels)
1289 CREATE TABLE /*_*/page_restrictions (
1290 -- Page to apply restrictions to (Foreign Key to page).
1291 pr_page int NOT NULL,
1292 -- The protection type (edit, move, etc)
1293 pr_type varbinary(60) NOT NULL,
1294 -- The protection level (Sysop, autoconfirmed, etc)
1295 pr_level varbinary(60) NOT NULL,
1296 -- Whether or not to cascade the protection down to pages transcluded.
1297 pr_cascade tinyint NOT NULL,
1298 -- Field for future support of per-user restriction.
1299 pr_user int NULL,
1300 -- Field for time-limited protection.
1301 pr_expiry varbinary(14) NULL,
1302 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1303 pr_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT
1304 ) /*$wgDBTableOptions*/;
1305
1306 CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
1307 CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
1308 CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
1309 CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);
1310
1311
1312 -- Protected titles - nonexistent pages that have been protected
1313 CREATE TABLE /*_*/protected_titles (
1314 pt_namespace int NOT NULL,
1315 pt_title varchar(255) binary NOT NULL,
1316 pt_user int unsigned NOT NULL,
1317 pt_reason tinyblob,
1318 pt_timestamp binary(14) NOT NULL,
1319 pt_expiry varbinary(14) NOT NULL default '',
1320 pt_create_perm varbinary(60) NOT NULL
1321 ) /*$wgDBTableOptions*/;
1322
1323 CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
1324 CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);
1325
1326
1327 -- Name/value pairs indexed by page_id
1328 CREATE TABLE /*_*/page_props (
1329 pp_page int NOT NULL,
1330 pp_propname varbinary(60) NOT NULL,
1331 pp_value blob NOT NULL
1332 ) /*$wgDBTableOptions*/;
1333
1334 CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
1335
1336
1337 -- A table to log updates, one text key row per update.
1338 CREATE TABLE /*_*/updatelog (
1339 ul_key varchar(255) NOT NULL PRIMARY KEY,
1340 ul_value blob
1341 ) /*$wgDBTableOptions*/;
1342
1343
1344 -- A table to track tags for revisions, logs and recent changes.
1345 CREATE TABLE /*_*/change_tag (
1346 -- RCID for the change
1347 ct_rc_id int NULL,
1348 -- LOGID for the change
1349 ct_log_id int NULL,
1350 -- REVID for the change
1351 ct_rev_id int NULL,
1352 -- Tag applied
1353 ct_tag varchar(255) NOT NULL,
1354 -- Parameters for the tag, presently unused
1355 ct_params blob NULL
1356 ) /*$wgDBTableOptions*/;
1357
1358 CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
1359 CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
1360 CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
1361 -- Covering index, so we can pull all the info only out of the index.
1362 CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
1363
1364
1365 -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
1366 -- that only works on MySQL 4.1+
1367 CREATE TABLE /*_*/tag_summary (
1368 -- RCID for the change
1369 ts_rc_id int NULL,
1370 -- LOGID for the change
1371 ts_log_id int NULL,
1372 -- REVID for the change
1373 ts_rev_id int NULL,
1374 -- Comma-separated list of tags
1375 ts_tags blob NOT NULL
1376 ) /*$wgDBTableOptions*/;
1377
1378 CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
1379 CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
1380 CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);
1381
1382
1383 CREATE TABLE /*_*/valid_tag (
1384 vt_tag varchar(255) NOT NULL PRIMARY KEY
1385 ) /*$wgDBTableOptions*/;
1386
1387 -- Table for storing localisation data
1388 CREATE TABLE /*_*/l10n_cache (
1389 -- Language code
1390 lc_lang varbinary(32) NOT NULL,
1391 -- Cache key
1392 lc_key varchar(255) NOT NULL,
1393 -- Value
1394 lc_value mediumblob NOT NULL
1395 ) /*$wgDBTableOptions*/;
1396 CREATE INDEX /*i*/lc_lang_key ON /*_*/l10n_cache (lc_lang, lc_key);
1397
1398 -- Table for storing JSON message blobs for the resource loader
1399 CREATE TABLE /*_*/msg_resource (
1400 -- Resource name
1401 mr_resource varchar(255) NOT NULL,
1402 -- Language code
1403 mr_lang varbinary(32) NOT NULL,
1404 -- JSON blob
1405 mr_blob mediumblob NOT NULL,
1406 -- Timestamp of last update
1407 mr_timestamp binary(14) NOT NULL
1408 ) /*$wgDBTableOptions*/;
1409 CREATE UNIQUE INDEX /*i*/mr_resource_lang ON /*_*/msg_resource (mr_resource, mr_lang);
1410
1411 -- Table for administering which message is contained in which resource
1412 CREATE TABLE /*_*/msg_resource_links (
1413 mrl_resource varchar(255) NOT NULL,
1414 -- Message key
1415 mrl_message varchar(255) NOT NULL
1416 ) /*$wgDBTableOptions*/;
1417 CREATE UNIQUE INDEX /*i*/mrl_message_resource ON /*_*/msg_resource_links (mrl_message, mrl_resource);
1418
1419 -- Table for tracking which local files a module depends on that aren't
1420 -- registered directly.
1421 -- Currently only used for tracking images that CSS depends on
1422 CREATE TABLE /*_*/module_deps (
1423 -- Module name
1424 md_module varchar(255) NOT NULL,
1425 -- Skin name
1426 md_skin varchar(32) NOT NULL,
1427 -- JSON blob with file dependencies
1428 md_deps mediumblob NOT NULL
1429 ) /*$wgDBTableOptions*/;
1430 CREATE UNIQUE INDEX /*i*/md_module_skin ON /*_*/module_deps (md_module, md_skin);
1431
1432 -- vim: sw=2 sts=2 et