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