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