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