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