a52d338f9b602ef4b18194237b3eb2e698193102
[lhc/web/wiklou.git] / maintenance / tables.sql
1 -- SQL to create the initial tables for the MediaWiki database.
2 -- This is read and executed by the install script; you should
3 -- not have to run it by itself unless doing a manual install.
4
5 -- This is a shared schema file used for both MySQL and SQLite installs.
6
7 --
8 -- General notes:
9 --
10 -- If possible, create tables as InnoDB to benefit from the
11 -- superior resiliency against crashes and ability to read
12 -- during writes (and write during reads!)
13 --
14 -- Only the 'searchindex' table requires MyISAM due to the
15 -- requirement for fulltext index support, which is missing
16 -- from InnoDB.
17 --
18 --
19 -- The MySQL table backend for MediaWiki currently uses
20 -- 14-character BINARY or VARBINARY fields to store timestamps.
21 -- The format is YYYYMMDDHHMMSS, which is derived from the
22 -- text format of MySQL's TIMESTAMP fields.
23 --
24 -- Historically TIMESTAMP fields were used, but abandoned
25 -- in early 2002 after a lot of trouble with the fields
26 -- auto-updating.
27 --
28 -- The Postgres backend uses DATETIME fields for timestamps,
29 -- and we will migrate the MySQL definitions at some point as
30 -- well.
31 --
32 --
33 -- The /*_*/ comments in this and other files are
34 -- replaced with the defined table prefix by the installer
35 -- and updater scripts. If you are installing or running
36 -- updates manually, you will need to manually insert the
37 -- table prefix if any when running these scripts.
38 --
39
40
41 --
42 -- The user table contains basic account information,
43 -- authentication keys, etc.
44 --
45 -- Some multi-wiki sites may share a single central user table
46 -- between separate wikis using the $wgSharedDB setting.
47 --
48 -- Note that when a external authentication plugin is used,
49 -- user table entries still need to be created to store
50 -- preferences and to key tracking information in the other
51 -- tables.
52 --
53 CREATE TABLE /*_*/user (
54 user_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
55
56 -- Usernames must be unique, must not be in the form of
57 -- an IP address. _Shouldn't_ allow slashes or case
58 -- conflicts. Spaces are allowed, and are _not_ converted
59 -- to underscores like titles. See the User::newFromName() for
60 -- the specific tests that usernames have to pass.
61 user_name varchar(255) binary NOT NULL default '',
62
63 -- Optional 'real name' to be displayed in credit listings
64 user_real_name varchar(255) binary NOT NULL default '',
65
66 -- Password hashes, normally hashed like so:
67 -- MD5(CONCAT(user_id,'-',MD5(plaintext_password))), see
68 -- wfEncryptPassword() in GlobalFunctions.php
69 user_password tinyblob NOT NULL,
70
71 -- When using 'mail me a new password', a random
72 -- password is generated and the hash stored here.
73 -- The previous password is left in place until
74 -- someone actually logs in with the new password,
75 -- at which point the hash is moved to user_password
76 -- and the old password is invalidated.
77 user_newpassword tinyblob NOT NULL,
78
79 -- Timestamp of the last time when a new password was
80 -- sent, for throttling purposes
81 user_newpass_time binary(14),
82
83 -- Note: email should be restricted, not public info.
84 -- Same with passwords.
85 user_email tinytext NOT NULL,
86
87 -- Newline-separated list of name=value defining the user
88 -- preferences
89 -- Now obsolete in favour of user_properties table;
90 -- old values will be migrated from here transparently.
91 user_options blob NOT NULL,
92
93 -- This is a timestamp which is updated when a user
94 -- logs in, logs out, changes preferences, or performs
95 -- some other action requiring HTML cache invalidation
96 -- to ensure that the UI is updated.
97 user_touched binary(14) NOT NULL default '',
98
99 -- A pseudorandomly generated value that is stored in
100 -- a cookie when the "remember password" feature is
101 -- used (previously, a hash of the password was used, but
102 -- this was vulnerable to cookie-stealing attacks)
103 user_token binary(32) NOT NULL default '',
104
105 -- Initially NULL; when a user's e-mail address has been
106 -- validated by returning with a mailed token, this is
107 -- set to the current timestamp.
108 user_email_authenticated binary(14),
109
110 -- Randomly generated token created when the e-mail address
111 -- is set and a confirmation test mail sent.
112 user_email_token binary(32),
113
114 -- Expiration date for the user_email_token
115 user_email_token_expires binary(14),
116
117 -- Timestamp of account registration.
118 -- Accounts predating this schema addition may contain NULL.
119 user_registration binary(14),
120
121 -- Count of edits and edit-like actions.
122 --
123 -- *NOT* intended to be an accurate copy of COUNT(*) WHERE rev_user=user_id
124 -- May contain NULL for old accounts if batch-update scripts haven't been
125 -- run, as well as listing deleted edits and other myriad ways it could be
126 -- out of sync.
127 --
128 -- Meant primarily for heuristic checks to give an impression of whether
129 -- the account has been used much.
130 --
131 user_editcount int
132 ) /*$wgDBTableOptions*/;
133
134 CREATE UNIQUE INDEX /*i*/user_name ON /*_*/user (user_name);
135 CREATE INDEX /*i*/user_email_token ON /*_*/user (user_email_token);
136
137
138 --
139 -- User permissions have been broken out to a separate table;
140 -- this allows sites with a shared user table to have different
141 -- permissions assigned to a user in each project.
142 --
143 -- This table replaces the old user_rights field which used a
144 -- comma-separated blob.
145 --
146 CREATE TABLE /*_*/user_groups (
147 -- Key to user_id
148 ug_user int unsigned NOT NULL default 0,
149
150 -- Group names are short symbolic string keys.
151 -- The set of group names is open-ended, though in practice
152 -- only some predefined ones are likely to be used.
153 --
154 -- At runtime $wgGroupPermissions will associate group keys
155 -- with particular permissions. A user will have the combined
156 -- permissions of any group they're explicitly in, plus
157 -- the implicit '*' and 'user' groups.
158 ug_group varbinary(16) NOT NULL default ''
159 ) /*$wgDBTableOptions*/;
160
161 CREATE UNIQUE INDEX /*i*/ug_user_group ON /*_*/user_groups (ug_user,ug_group);
162 CREATE INDEX /*i*/ug_group ON /*_*/user_groups (ug_group);
163
164
165 --
166 -- Stores notifications of user talk page changes, for the display
167 -- of the "you have new messages" box
168 --
169 CREATE TABLE /*_*/user_newtalk (
170 -- Key to user.user_id
171 user_id int NOT NULL default 0,
172 -- If the user is an anonymous user their IP address is stored here
173 -- since the user_id of 0 is ambiguous
174 user_ip varbinary(40) NOT NULL default '',
175 -- The highest timestamp of revisions of the talk page viewed
176 -- by this user
177 user_last_timestamp binary(14) NOT NULL default ''
178 ) /*$wgDBTableOptions*/;
179
180 -- Indexes renamed for SQLite in 1.14
181 CREATE INDEX /*i*/un_user_id ON /*_*/user_newtalk (user_id);
182 CREATE INDEX /*i*/un_user_ip ON /*_*/user_newtalk (user_ip);
183
184
185 --
186 -- User preferences and perhaps other fun stuff. :)
187 -- Replaces the old user.user_options blob, with a couple nice properties:
188 --
189 -- 1) We only store non-default settings, so changes to the defauls
190 -- are now reflected for everybody, not just new accounts.
191 -- 2) We can more easily do bulk lookups, statistics, or modifications of
192 -- saved options since it's a sane table structure.
193 --
194 CREATE TABLE /*_*/user_properties (
195 -- Foreign key to user.user_id
196 up_user int NOT NULL,
197
198 -- Name of the option being saved. This is indexed for bulk lookup.
199 up_property varbinary(32) NOT NULL,
200
201 -- Property value as a string.
202 up_value blob
203 ) /*$wgDBTableOptions*/;
204
205 CREATE UNIQUE INDEX /*i*/user_properties_user_property ON /*_*/user_properties (up_user,up_property);
206 CREATE INDEX /*i*/user_properties_property ON /*_*/user_properties (up_property);
207
208 --
209 -- Core of the wiki: each page has an entry here which identifies
210 -- it by title and contains some essential metadata.
211 --
212 CREATE TABLE /*_*/page (
213 -- Unique identifier number. The page_id will be preserved across
214 -- edits and rename operations, but not deletions and recreations.
215 page_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
216
217 -- A page name is broken into a namespace and a title.
218 -- The namespace keys are UI-language-independent constants,
219 -- defined in includes/Defines.php
220 page_namespace int NOT NULL,
221
222 -- The rest of the title, as text.
223 -- Spaces are transformed into underscores in title storage.
224 page_title varchar(255) binary NOT NULL,
225
226 -- Comma-separated set of permission keys indicating who
227 -- can move or edit the page.
228 page_restrictions tinyblob NOT NULL,
229
230 -- Number of times this page has been viewed.
231 page_counter bigint unsigned NOT NULL default 0,
232
233 -- 1 indicates the article is a redirect.
234 page_is_redirect tinyint unsigned NOT NULL default 0,
235
236 -- 1 indicates this is a new entry, with only one edit.
237 -- Not all pages with one edit are new pages.
238 page_is_new tinyint unsigned NOT NULL default 0,
239
240 -- Random value between 0 and 1, used for Special:Randompage
241 page_random real unsigned NOT NULL,
242
243 -- This timestamp is updated whenever the page changes in
244 -- a way requiring it to be re-rendered, invalidating caches.
245 -- Aside from editing this includes permission changes,
246 -- creation or deletion of linked pages, and alteration
247 -- of contained templates.
248 page_touched binary(14) NOT NULL default '',
249
250 -- Handy key to revision.rev_id of the current revision.
251 -- This may be 0 during page creation, but that shouldn't
252 -- happen outside of a transaction... hopefully.
253 page_latest int unsigned NOT NULL,
254
255 -- Uncompressed length in bytes of the page's current source text.
256 page_len int unsigned NOT NULL
257 ) /*$wgDBTableOptions*/;
258
259 CREATE UNIQUE INDEX /*i*/name_title ON /*_*/page (page_namespace,page_title);
260 CREATE INDEX /*i*/page_random ON /*_*/page (page_random);
261 CREATE INDEX /*i*/page_len ON /*_*/page (page_len);
262
263
264 --
265 -- Every edit of a page creates also a revision row.
266 -- This stores metadata about the revision, and a reference
267 -- to the text storage backend.
268 --
269 CREATE TABLE /*_*/revision (
270 rev_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
271
272 -- Key to page_id. This should _never_ be invalid.
273 rev_page int unsigned NOT NULL,
274
275 -- Key to text.old_id, where the actual bulk text is stored.
276 -- It's possible for multiple revisions to use the same text,
277 -- for instance revisions where only metadata is altered
278 -- or a rollback to a previous version.
279 rev_text_id int unsigned NOT NULL,
280
281 -- Text comment summarizing the change.
282 -- This text is shown in the history and other changes lists,
283 -- rendered in a subset of wiki markup by Linker::formatComment()
284 rev_comment tinyblob NOT NULL,
285
286 -- Key to user.user_id of the user who made this edit.
287 -- Stores 0 for anonymous edits and for some mass imports.
288 rev_user int unsigned NOT NULL default 0,
289
290 -- Text username or IP address of the editor.
291 rev_user_text varchar(255) binary NOT NULL default '',
292
293 -- Timestamp
294 rev_timestamp binary(14) NOT NULL default '',
295
296 -- Records whether the user marked the 'minor edit' checkbox.
297 -- Many automated edits are marked as minor.
298 rev_minor_edit tinyint unsigned NOT NULL default 0,
299
300 -- Not yet used; reserved for future changes to the deletion system.
301 rev_deleted tinyint unsigned NOT NULL default 0,
302
303 -- Length of this revision in bytes
304 rev_len int unsigned,
305
306 -- Key to revision.rev_id
307 -- This field is used to add support for a tree structure (The Adjacency List Model)
308 rev_parent_id int unsigned default NULL
309
310 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
311 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
312
313 CREATE UNIQUE INDEX /*i*/rev_page_id ON /*_*/revision (rev_page, rev_id);
314 CREATE INDEX /*i*/rev_timestamp ON /*_*/revision (rev_timestamp);
315 CREATE INDEX /*i*/page_timestamp ON /*_*/revision (rev_page,rev_timestamp);
316 CREATE INDEX /*i*/user_timestamp ON /*_*/revision (rev_user,rev_timestamp);
317 CREATE INDEX /*i*/usertext_timestamp ON /*_*/revision (rev_user_text,rev_timestamp);
318
319 --
320 -- Holds text of individual page revisions.
321 --
322 -- Field names are a holdover from the 'old' revisions table in
323 -- MediaWiki 1.4 and earlier: an upgrade will transform that
324 -- table into the 'text' table to minimize unnecessary churning
325 -- and downtime. If upgrading, the other fields will be left unused.
326 --
327 CREATE TABLE /*_*/text (
328 -- Unique text storage key number.
329 -- Note that the 'oldid' parameter used in URLs does *not*
330 -- refer to this number anymore, but to rev_id.
331 --
332 -- revision.rev_text_id is a key to this column
333 old_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
334
335 -- Depending on the contents of the old_flags field, the text
336 -- may be convenient plain text, or it may be funkily encoded.
337 old_text mediumblob NOT NULL,
338
339 -- Comma-separated list of flags:
340 -- gzip: text is compressed with PHP's gzdeflate() function.
341 -- utf8: text was stored as UTF-8.
342 -- If $wgLegacyEncoding option is on, rows *without* this flag
343 -- will be converted to UTF-8 transparently at load time.
344 -- object: text field contained a serialized PHP object.
345 -- The object either contains multiple versions compressed
346 -- together to achieve a better compression ratio, or it refers
347 -- to another row where the text can be found.
348 old_flags tinyblob NOT NULL
349 ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=10240;
350 -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
351
352
353 --
354 -- Holding area for deleted articles, which may be viewed
355 -- or restored by admins through the Special:Undelete interface.
356 -- The fields generally correspond to the page, revision, and text
357 -- fields, with several caveats.
358 --
359 CREATE TABLE /*_*/archive (
360 ar_namespace int NOT NULL default 0,
361 ar_title varchar(255) binary NOT NULL default '',
362
363 -- Newly deleted pages will not store text in this table,
364 -- but will reference the separately existing text rows.
365 -- This field is retained for backwards compatibility,
366 -- so old archived pages will remain accessible after
367 -- upgrading from 1.4 to 1.5.
368 -- Text may be gzipped or otherwise funky.
369 ar_text mediumblob NOT NULL,
370
371 -- Basic revision stuff...
372 ar_comment tinyblob NOT NULL,
373 ar_user int unsigned NOT NULL default 0,
374 ar_user_text varchar(255) binary NOT NULL,
375 ar_timestamp binary(14) NOT NULL default '',
376 ar_minor_edit tinyint NOT NULL default 0,
377
378 -- See ar_text note.
379 ar_flags tinyblob NOT NULL,
380
381 -- When revisions are deleted, their unique rev_id is stored
382 -- here so it can be retained after undeletion. This is necessary
383 -- to retain permalinks to given revisions after accidental delete
384 -- cycles or messy operations like history merges.
385 --
386 -- Old entries from 1.4 will be NULL here, and a new rev_id will
387 -- be created on undeletion for those revisions.
388 ar_rev_id int unsigned,
389
390 -- For newly deleted revisions, this is the text.old_id key to the
391 -- actual stored text. To avoid breaking the block-compression scheme
392 -- and otherwise making storage changes harder, the actual text is
393 -- *not* deleted from the text table, merely hidden by removal of the
394 -- page and revision entries.
395 --
396 -- Old entries deleted under 1.2-1.4 will have NULL here, and their
397 -- ar_text and ar_flags fields will be used to create a new text
398 -- row upon undeletion.
399 ar_text_id int unsigned,
400
401 -- rev_deleted for archives
402 ar_deleted tinyint unsigned NOT NULL default 0,
403
404 -- Length of this revision in bytes
405 ar_len int unsigned,
406
407 -- Reference to page_id. Useful for sysadmin fixing of large pages
408 -- merged together in the archives, or for cleanly restoring a page
409 -- at its original ID number if possible.
410 --
411 -- Will be NULL for pages deleted prior to 1.11.
412 ar_page_id int unsigned,
413
414 -- Original previous revision
415 ar_parent_id int unsigned default NULL
416 ) /*$wgDBTableOptions*/;
417
418 CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp);
419 CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp);
420
421
422 --
423 -- Track page-to-page hyperlinks within the wiki.
424 --
425 CREATE TABLE /*_*/pagelinks (
426 -- Key to the page_id of the page containing the link.
427 pl_from int unsigned NOT NULL default 0,
428
429 -- Key to page_namespace/page_title of the target page.
430 -- The target page may or may not exist, and due to renames
431 -- and deletions may refer to different page records as time
432 -- goes by.
433 pl_namespace int NOT NULL default 0,
434 pl_title varchar(255) binary NOT NULL default ''
435 ) /*$wgDBTableOptions*/;
436
437 CREATE UNIQUE INDEX /*i*/pl_from ON /*_*/pagelinks (pl_from,pl_namespace,pl_title);
438 CREATE UNIQUE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from);
439
440
441 --
442 -- Track template inclusions.
443 --
444 CREATE TABLE /*_*/templatelinks (
445 -- Key to the page_id of the page containing the link.
446 tl_from int unsigned NOT NULL default 0,
447
448 -- Key to page_namespace/page_title of the target page.
449 -- The target page may or may not exist, and due to renames
450 -- and deletions may refer to different page records as time
451 -- goes by.
452 tl_namespace int NOT NULL default 0,
453 tl_title varchar(255) binary NOT NULL default ''
454 ) /*$wgDBTableOptions*/;
455
456 CREATE UNIQUE INDEX /*i*/tl_from ON /*_*/templatelinks (tl_from,tl_namespace,tl_title);
457 CREATE UNIQUE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from);
458
459
460 --
461 -- Track links to images *used inline*
462 -- We don't distinguish live from broken links here, so
463 -- they do not need to be changed on upload/removal.
464 --
465 CREATE TABLE /*_*/imagelinks (
466 -- Key to page_id of the page containing the image / media link.
467 il_from int unsigned NOT NULL default 0,
468
469 -- Filename of target image.
470 -- This is also the page_title of the file's description page;
471 -- all such pages are in namespace 6 (NS_FILE).
472 il_to varchar(255) binary NOT NULL default ''
473 ) /*$wgDBTableOptions*/;
474
475 CREATE UNIQUE INDEX /*i*/il_from ON /*_*/imagelinks (il_from,il_to);
476 CREATE UNIQUE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from);
477
478
479 --
480 -- Track category inclusions *used inline*
481 -- This tracks a single level of category membership
482 --
483 CREATE TABLE /*_*/categorylinks (
484 -- Key to page_id of the page defined as a category member.
485 cl_from int unsigned NOT NULL default 0,
486
487 -- Name of the category.
488 -- This is also the page_title of the category's description page;
489 -- all such pages are in namespace 14 (NS_CATEGORY).
490 cl_to varchar(255) binary NOT NULL default '',
491
492 -- The title of the linking page, or an optional override
493 -- to determine sort order. Sorting is by binary order, which
494 -- isn't always ideal, but collations seem to be an exciting
495 -- and dangerous new world in MySQL... The sortkey is updated
496 -- if no override exists and cl_from is renamed.
497 --
498 -- Truncate so that the cl_sortkey key fits in 1000 bytes
499 -- (MyISAM 5 with server_character_set=utf8)
500 cl_sortkey varchar(70) binary NOT NULL default '',
501
502 -- This isn't really used at present. Provided for an optional
503 -- sorting method by approximate addition time.
504 cl_timestamp timestamp NOT NULL
505 ) /*$wgDBTableOptions*/;
506
507 CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to);
508
509 -- We always sort within a given category...
510 CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_sortkey,cl_from);
511
512 -- Not really used?
513 CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);
514
515
516 --
517 -- Track all existing categories. Something is a category if 1) it has an en-
518 -- try somewhere in categorylinks, or 2) it once did. Categories might not
519 -- have corresponding pages, so they need to be tracked separately.
520 --
521 CREATE TABLE /*_*/category (
522 -- Primary key
523 cat_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
524
525 -- Name of the category, in the same form as page_title (with underscores).
526 -- If there is a category page corresponding to this category, by definition,
527 -- it has this name (in the Category namespace).
528 cat_title varchar(255) binary NOT NULL,
529
530 -- The numbers of member pages (including categories and media), subcatego-
531 -- ries, and Image: namespace members, respectively. These are signed to
532 -- make underflow more obvious. We make the first number include the second
533 -- two for better sorting: subtracting for display is easy, adding for order-
534 -- ing is not.
535 cat_pages int signed NOT NULL default 0,
536 cat_subcats int signed NOT NULL default 0,
537 cat_files int signed NOT NULL default 0,
538
539 -- Reserved for future use
540 cat_hidden tinyint unsigned NOT NULL default 0
541 ) /*$wgDBTableOptions*/;
542
543 CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);
544
545 -- For Special:Mostlinkedcategories
546 CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);
547
548
549 --
550 -- Track links to external URLs
551 --
552 CREATE TABLE /*_*/externallinks (
553 -- page_id of the referring page
554 el_from int unsigned NOT NULL default 0,
555
556 -- The URL
557 el_to blob NOT NULL,
558
559 -- In the case of HTTP URLs, this is the URL with any username or password
560 -- removed, and with the labels in the hostname reversed and converted to
561 -- lower case. An extra dot is added to allow for matching of either
562 -- example.com or *.example.com in a single scan.
563 -- Example:
564 -- http://user:password@sub.example.com/page.html
565 -- becomes
566 -- http://com.example.sub./page.html
567 -- which allows for fast searching for all pages under example.com with the
568 -- clause:
569 -- WHERE el_index LIKE 'http://com.example.%'
570 el_index blob NOT NULL
571 ) /*$wgDBTableOptions*/;
572
573 CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from, el_to(40));
574 CREATE INDEX /*i*/el_to ON /*_*/externallinks (el_to(60), el_from);
575 CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index(60));
576
577
578 --
579 -- Track interlanguage links
580 --
581 CREATE TABLE /*_*/langlinks (
582 -- page_id of the referring page
583 ll_from int unsigned NOT NULL default 0,
584
585 -- Language code of the target
586 ll_lang varbinary(20) NOT NULL default '',
587
588 -- Title of the target, including namespace
589 ll_title varchar(255) binary NOT NULL default ''
590 ) /*$wgDBTableOptions*/;
591
592 CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang);
593 CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);
594
595
596 --
597 -- Contains a single row with some aggregate info
598 -- on the state of the site.
599 --
600 CREATE TABLE /*_*/site_stats (
601 -- The single row should contain 1 here.
602 ss_row_id int unsigned NOT NULL,
603
604 -- Total number of page views, if hit counters are enabled.
605 ss_total_views bigint unsigned default 0,
606
607 -- Total number of edits performed.
608 ss_total_edits bigint unsigned default 0,
609
610 -- An approximate count of pages matching the following criteria:
611 -- * in namespace 0
612 -- * not a redirect
613 -- * contains the text '[['
614 -- See Article::isCountable() in includes/Article.php
615 ss_good_articles bigint unsigned default 0,
616
617 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
618 ss_total_pages bigint default '-1',
619
620 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
621 ss_users bigint default '-1',
622
623 -- Number of users that still edit
624 ss_active_users bigint default '-1',
625
626 -- Deprecated, no longer updated as of 1.5
627 ss_admins int default '-1',
628
629 -- Number of images, equivalent to SELECT COUNT(*) FROM image
630 ss_images int default 0
631 ) /*$wgDBTableOptions*/;
632
633 -- Pointless index to assuage developer superstitions
634 CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id);
635
636
637 --
638 -- Stores an ID for every time any article is visited;
639 -- depending on $wgHitcounterUpdateFreq, it is
640 -- periodically cleared and the page_counter column
641 -- in the page table updated for all the articles
642 -- that have been visited.)
643 --
644 CREATE TABLE /*_*/hitcounter (
645 hc_id int unsigned NOT NULL
646 ) ENGINE=HEAP MAX_ROWS=25000;
647
648
649 --
650 -- The internet is full of jerks, alas. Sometimes it's handy
651 -- to block a vandal or troll account.
652 --
653 CREATE TABLE /*_*/ipblocks (
654 -- Primary key, introduced for privacy.
655 ipb_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
656
657 -- Blocked IP address in dotted-quad form or user name.
658 ipb_address tinyblob NOT NULL,
659
660 -- Blocked user ID or 0 for IP blocks.
661 ipb_user int unsigned NOT NULL default 0,
662
663 -- User ID who made the block.
664 ipb_by int unsigned NOT NULL default 0,
665
666 -- User name of blocker
667 ipb_by_text varchar(255) binary NOT NULL default '',
668
669 -- Text comment made by blocker.
670 ipb_reason tinyblob NOT NULL,
671
672 -- Creation (or refresh) date in standard YMDHMS form.
673 -- IP blocks expire automatically.
674 ipb_timestamp binary(14) NOT NULL default '',
675
676 -- Indicates that the IP address was banned because a banned
677 -- user accessed a page through it. If this is 1, ipb_address
678 -- will be hidden, and the block identified by block ID number.
679 ipb_auto bool NOT NULL default 0,
680
681 -- If set to 1, block applies only to logged-out users
682 ipb_anon_only bool NOT NULL default 0,
683
684 -- Block prevents account creation from matching IP addresses
685 ipb_create_account bool NOT NULL default 1,
686
687 -- Block triggers autoblocks
688 ipb_enable_autoblock bool NOT NULL default '1',
689
690 -- Time at which the block will expire.
691 -- May be "infinity"
692 ipb_expiry varbinary(14) NOT NULL default '',
693
694 -- Start and end of an address range, in hexadecimal
695 -- Size chosen to allow IPv6
696 ipb_range_start tinyblob NOT NULL,
697 ipb_range_end tinyblob NOT NULL,
698
699 -- Flag for entries hidden from users and Sysops
700 ipb_deleted bool NOT NULL default 0,
701
702 -- Block prevents user from accessing Special:Emailuser
703 ipb_block_email bool NOT NULL default 0,
704
705 -- Block allows user to edit their own talk page
706 ipb_allow_usertalk bool NOT NULL default 0
707
708 ) /*$wgDBTableOptions*/;
709
710 -- Unique index to support "user already blocked" messages
711 -- Any new options which prevent collisions should be included
712 CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only);
713
714 CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
715 CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start(8), ipb_range_end(8));
716 CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
717 CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
718
719
720 --
721 -- Uploaded images and other files.
722 --
723 CREATE TABLE /*_*/image (
724 -- Filename.
725 -- This is also the title of the associated description page,
726 -- which will be in namespace 6 (NS_FILE).
727 img_name varchar(255) binary NOT NULL default '' PRIMARY KEY,
728
729 -- File size in bytes.
730 img_size int unsigned NOT NULL default 0,
731
732 -- For images, size in pixels.
733 img_width int NOT NULL default 0,
734 img_height int NOT NULL default 0,
735
736 -- Extracted EXIF metadata stored as a serialized PHP array.
737 img_metadata mediumblob NOT NULL,
738
739 -- For images, bits per pixel if known.
740 img_bits int NOT NULL default 0,
741
742 -- Media type as defined by the MEDIATYPE_xxx constants
743 img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
744
745 -- major part of a MIME media type as defined by IANA
746 -- see http://www.iana.org/assignments/media-types/
747 img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
748
749 -- minor part of a MIME media type as defined by IANA
750 -- the minor parts are not required to adher to any standard
751 -- but should be consistent throughout the database
752 -- see http://www.iana.org/assignments/media-types/
753 img_minor_mime varbinary(32) NOT NULL default "unknown",
754
755 -- Description field as entered by the uploader.
756 -- This is displayed in image upload history and logs.
757 img_description tinyblob NOT NULL,
758
759 -- user_id and user_name of uploader.
760 img_user int unsigned NOT NULL default 0,
761 img_user_text varchar(255) binary NOT NULL,
762
763 -- Time of the upload.
764 img_timestamp varbinary(14) NOT NULL default '',
765
766 -- SHA-1 content hash in base-36
767 img_sha1 varbinary(32) NOT NULL default ''
768 ) /*$wgDBTableOptions*/;
769
770 CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
771 -- Used by Special:Imagelist for sort-by-size
772 CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
773 -- Used by Special:Newimages and Special:Imagelist
774 CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
775 -- Used in API and duplicate search
776 CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1);
777
778
779 --
780 -- Previous revisions of uploaded files.
781 -- Awkwardly, image rows have to be moved into
782 -- this table at re-upload time.
783 --
784 CREATE TABLE /*_*/oldimage (
785 -- Base filename: key to image.img_name
786 oi_name varchar(255) binary NOT NULL default '',
787
788 -- Filename of the archived file.
789 -- This is generally a timestamp and '!' prepended to the base name.
790 oi_archive_name varchar(255) binary NOT NULL default '',
791
792 -- Other fields as in image...
793 oi_size int unsigned NOT NULL default 0,
794 oi_width int NOT NULL default 0,
795 oi_height int NOT NULL default 0,
796 oi_bits int NOT NULL default 0,
797 oi_description tinyblob NOT NULL,
798 oi_user int unsigned NOT NULL default 0,
799 oi_user_text varchar(255) binary NOT NULL,
800 oi_timestamp binary(14) NOT NULL default '',
801
802 oi_metadata mediumblob NOT NULL,
803 oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
804 oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") NOT NULL default "unknown",
805 oi_minor_mime varbinary(32) NOT NULL default "unknown",
806 oi_deleted tinyint unsigned NOT NULL default 0,
807 oi_sha1 varbinary(32) NOT NULL default ''
808 ) /*$wgDBTableOptions*/;
809
810 CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
811 CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
812 -- oi_archive_name truncated to 14 to avoid key length overflow
813 CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name(14));
814 CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1);
815
816
817 --
818 -- Record of deleted file data
819 --
820 CREATE TABLE /*_*/filearchive (
821 -- Unique row id
822 fa_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
823
824 -- Original base filename; key to image.img_name, page.page_title, etc
825 fa_name varchar(255) binary NOT NULL default '',
826
827 -- Filename of archived file, if an old revision
828 fa_archive_name varchar(255) binary default '',
829
830 -- Which storage bin (directory tree or object store) the file data
831 -- is stored in. Should be 'deleted' for files that have been deleted;
832 -- any other bin is not yet in use.
833 fa_storage_group varbinary(16),
834
835 -- SHA-1 of the file contents plus extension, used as a key for storage.
836 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
837 --
838 -- If NULL, the file was missing at deletion time or has been purged
839 -- from the archival storage.
840 fa_storage_key varbinary(64) default '',
841
842 -- Deletion information, if this file is deleted.
843 fa_deleted_user int,
844 fa_deleted_timestamp binary(14) default '',
845 fa_deleted_reason text,
846
847 -- Duped fields from image
848 fa_size int unsigned default 0,
849 fa_width int default 0,
850 fa_height int default 0,
851 fa_metadata mediumblob,
852 fa_bits int default 0,
853 fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
854 fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart") default "unknown",
855 fa_minor_mime varbinary(32) default "unknown",
856 fa_description tinyblob,
857 fa_user int unsigned default 0,
858 fa_user_text varchar(255) binary,
859 fa_timestamp binary(14) default '',
860
861 -- Visibility of deleted revisions, bitfield
862 fa_deleted tinyint unsigned NOT NULL default 0
863 ) /*$wgDBTableOptions*/;
864
865 -- pick out by image name
866 CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
867 -- pick out dupe files
868 CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
869 -- sort by deletion time
870 CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
871 -- sort by uploader
872 CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
873
874
875 --
876 -- Primarily a summary table for Special:Recentchanges,
877 -- this table contains some additional info on edits from
878 -- the last few days, see Article::editUpdates()
879 --
880 CREATE TABLE /*_*/recentchanges (
881 rc_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
882 rc_timestamp varbinary(14) NOT NULL default '',
883 rc_cur_time varbinary(14) NOT NULL default '',
884
885 -- As in revision
886 rc_user int unsigned NOT NULL default 0,
887 rc_user_text varchar(255) binary NOT NULL,
888
889 -- When pages are renamed, their RC entries do _not_ change.
890 rc_namespace int NOT NULL default 0,
891 rc_title varchar(255) binary NOT NULL default '',
892
893 -- as in revision...
894 rc_comment varchar(255) binary NOT NULL default '',
895 rc_minor tinyint unsigned NOT NULL default 0,
896
897 -- Edits by user accounts with the 'bot' rights key are
898 -- marked with a 1 here, and will be hidden from the
899 -- default view.
900 rc_bot tinyint unsigned NOT NULL default 0,
901
902 rc_new tinyint unsigned NOT NULL default 0,
903
904 -- Key to page_id (was cur_id prior to 1.5).
905 -- This will keep links working after moves while
906 -- retaining the at-the-time name in the changes list.
907 rc_cur_id int unsigned NOT NULL default 0,
908
909 -- rev_id of the given revision
910 rc_this_oldid int unsigned NOT NULL default 0,
911
912 -- rev_id of the prior revision, for generating diff links.
913 rc_last_oldid int unsigned NOT NULL default 0,
914
915 -- These may no longer be used, with the new move log.
916 rc_type tinyint unsigned NOT NULL default 0,
917 rc_moved_to_ns tinyint unsigned NOT NULL default 0,
918 rc_moved_to_title varchar(255) binary NOT NULL default '',
919
920 -- If the Recent Changes Patrol option is enabled,
921 -- users may mark edits as having been reviewed to
922 -- remove a warning flag on the RC list.
923 -- A value of 1 indicates the page has been reviewed.
924 rc_patrolled tinyint unsigned NOT NULL default 0,
925
926 -- Recorded IP address the edit was made from, if the
927 -- $wgPutIPinRC option is enabled.
928 rc_ip varbinary(40) NOT NULL default '',
929
930 -- Text length in characters before
931 -- and after the edit
932 rc_old_len int,
933 rc_new_len int,
934
935 -- Visibility of recent changes items, bitfield
936 rc_deleted tinyint unsigned NOT NULL default 0,
937
938 -- Value corresonding to log_id, specific log entries
939 rc_logid int unsigned NOT NULL default 0,
940 -- Store log type info here, or null
941 rc_log_type varbinary(255) NULL default NULL,
942 -- Store log action or null
943 rc_log_action varbinary(255) NULL default NULL,
944 -- Log params
945 rc_params blob NULL
946 ) /*$wgDBTableOptions*/;
947
948 CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
949 CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
950 CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
951 CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
952 CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
953 CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
954 CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);
955
956
957 CREATE TABLE /*_*/watchlist (
958 -- Key to user.user_id
959 wl_user int unsigned NOT NULL,
960
961 -- Key to page_namespace/page_title
962 -- Note that users may watch pages which do not exist yet,
963 -- or existed in the past but have been deleted.
964 wl_namespace int NOT NULL default 0,
965 wl_title varchar(255) binary NOT NULL default '',
966
967 -- Timestamp when user was last sent a notification e-mail;
968 -- cleared when the user visits the page.
969 wl_notificationtimestamp varbinary(14)
970
971 ) /*$wgDBTableOptions*/;
972
973 CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
974 CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);
975
976
977 --
978 -- Used by the math module to keep track
979 -- of previously-rendered items.
980 --
981 CREATE TABLE /*_*/math (
982 -- Binary MD5 hash of the latex fragment, used as an identifier key.
983 math_inputhash varbinary(16) NOT NULL,
984
985 -- Not sure what this is, exactly...
986 math_outputhash varbinary(16) NOT NULL,
987
988 -- texvc reports how well it thinks the HTML conversion worked;
989 -- if it's a low level the PNG rendering may be preferred.
990 math_html_conservativeness tinyint NOT NULL,
991
992 -- HTML output from texvc, if any
993 math_html text,
994
995 -- MathML output from texvc, if any
996 math_mathml text
997 ) /*$wgDBTableOptions*/;
998
999 CREATE UNIQUE INDEX /*i*/math_inputhash ON /*_*/math (math_inputhash);
1000
1001
1002 --
1003 -- When using the default MySQL search backend, page titles
1004 -- and text are munged to strip markup, do Unicode case folding,
1005 -- and prepare the result for MySQL's fulltext index.
1006 --
1007 -- This table must be MyISAM; InnoDB does not support the needed
1008 -- fulltext index.
1009 --
1010 CREATE TABLE /*_*/searchindex (
1011 -- Key to page_id
1012 si_page int unsigned NOT NULL,
1013
1014 -- Munged version of title
1015 si_title varchar(255) NOT NULL default '',
1016
1017 -- Munged version of body text
1018 si_text mediumtext NOT NULL
1019 ) ENGINE=MyISAM;
1020
1021 CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
1022 CREATE FULLTEXT INDEX /*i*/si_title ON /*_*/searchindex (si_title);
1023 CREATE FULLTEXT INDEX /*i*/si_text ON /*_*/searchindex (si_text);
1024
1025
1026 --
1027 -- Recognized interwiki link prefixes
1028 --
1029 CREATE TABLE /*_*/interwiki (
1030 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
1031 iw_prefix varchar(32) NOT NULL,
1032
1033 -- The URL of the wiki, with "$1" as a placeholder for an article name.
1034 -- Any spaces in the name will be transformed to underscores before
1035 -- insertion.
1036 iw_url blob NOT NULL,
1037
1038 -- A boolean value indicating whether the wiki is in this project
1039 -- (used, for example, to detect redirect loops)
1040 iw_local bool NOT NULL,
1041
1042 -- Boolean value indicating whether interwiki transclusions are allowed.
1043 iw_trans tinyint NOT NULL default 0
1044 ) /*$wgDBTableOptions*/;
1045
1046 CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);
1047
1048
1049 --
1050 -- Used for caching expensive grouped queries
1051 --
1052 CREATE TABLE /*_*/querycache (
1053 -- A key name, generally the base name of of the special page.
1054 qc_type varbinary(32) NOT NULL,
1055
1056 -- Some sort of stored value. Sizes, counts...
1057 qc_value int unsigned NOT NULL default 0,
1058
1059 -- Target namespace+title
1060 qc_namespace int NOT NULL default 0,
1061 qc_title varchar(255) binary NOT NULL default ''
1062 ) /*$wgDBTableOptions*/;
1063
1064 CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);
1065
1066
1067 --
1068 -- For a few generic cache operations if not using Memcached
1069 --
1070 CREATE TABLE /*_*/objectcache (
1071 keyname varbinary(255) NOT NULL default '' PRIMARY KEY,
1072 value mediumblob,
1073 exptime datetime
1074 ) /*$wgDBTableOptions*/;
1075 CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);
1076
1077
1078 --
1079 -- Cache of interwiki transclusion
1080 --
1081 CREATE TABLE /*_*/transcache (
1082 tc_url varbinary(255) NOT NULL,
1083 tc_contents text,
1084 tc_time int NOT NULL
1085 ) /*$wgDBTableOptions*/;
1086
1087 CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url);
1088
1089
1090 CREATE TABLE /*_*/logging (
1091 -- Log ID, for referring to this specific log entry, probably for deletion and such.
1092 log_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1093
1094 -- Symbolic keys for the general log type and the action type
1095 -- within the log. The output format will be controlled by the
1096 -- action field, but only the type controls categorization.
1097 log_type varbinary(10) NOT NULL default '',
1098 log_action varbinary(10) NOT NULL default '',
1099
1100 -- Timestamp. Duh.
1101 log_timestamp binary(14) NOT NULL default '19700101000000',
1102
1103 -- The user who performed this action; key to user_id
1104 log_user int unsigned NOT NULL default 0,
1105
1106 -- Key to the page affected. Where a user is the target,
1107 -- this will point to the user page.
1108 log_namespace int NOT NULL default 0,
1109 log_title varchar(255) binary NOT NULL default '',
1110
1111 -- Freeform text. Interpreted as edit history comments.
1112 log_comment varchar(255) NOT NULL default '',
1113
1114 -- LF separated list of miscellaneous parameters
1115 log_params blob NOT NULL,
1116
1117 -- rev_deleted for logs
1118 log_deleted tinyint unsigned NOT NULL default 0
1119 ) /*$wgDBTableOptions*/;
1120
1121 CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
1122 CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
1123 CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
1124 CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
1125
1126
1127 CREATE TABLE /*_*/log_search (
1128 -- The type of ID (rev ID, log ID, rev timestamp, username)
1129 ls_field varbinary(32) NOT NULL,
1130 -- The value of the ID
1131 ls_value varchar(255) NOT NULL,
1132 -- Key to log_id
1133 ls_log_id int unsigned NOT NULL default 0
1134 ) /*$wgDBTableOptions*/;
1135 CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id);
1136 CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);
1137
1138
1139 CREATE TABLE /*_*/trackbacks (
1140 tb_id int PRIMARY KEY AUTO_INCREMENT,
1141 tb_page int REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
1142 tb_title varchar(255) NOT NULL,
1143 tb_url blob NOT NULL,
1144 tb_ex text,
1145 tb_name varchar(255)
1146 ) /*$wgDBTableOptions*/;
1147 CREATE INDEX /*i*/tb_page ON /*_*/trackbacks (tb_page);
1148
1149
1150 -- Jobs performed by parallel apache threads or a command-line daemon
1151 CREATE TABLE /*_*/job (
1152 job_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
1153
1154 -- Command name
1155 -- Limited to 60 to prevent key length overflow
1156 job_cmd varbinary(60) NOT NULL default '',
1157
1158 -- Namespace and title to act on
1159 -- Should be 0 and '' if the command does not operate on a title
1160 job_namespace int NOT NULL,
1161 job_title varchar(255) binary NOT NULL,
1162
1163 -- Any other parameters to the command
1164 -- Stored as a PHP serialized array, or an empty string if there are no parameters
1165 job_params blob NOT NULL
1166 ) /*$wgDBTableOptions*/;
1167
1168 CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title);
1169
1170
1171 -- Details of updates to cached special pages
1172 CREATE TABLE /*_*/querycache_info (
1173 -- Special page name
1174 -- Corresponds to a qc_type value
1175 qci_type varbinary(32) NOT NULL default '',
1176
1177 -- Timestamp of last update
1178 qci_timestamp binary(14) NOT NULL default '19700101000000'
1179 ) /*$wgDBTableOptions*/;
1180
1181 CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type);
1182
1183
1184 -- For each redirect, this table contains exactly one row defining its target
1185 CREATE TABLE /*_*/redirect (
1186 -- Key to the page_id of the redirect page
1187 rd_from int unsigned NOT NULL default 0 PRIMARY KEY,
1188
1189 -- Key to page_namespace/page_title of the target page.
1190 -- The target page may or may not exist, and due to renames
1191 -- and deletions may refer to different page records as time
1192 -- goes by.
1193 rd_namespace int NOT NULL default 0,
1194 rd_title varchar(255) binary NOT NULL default '',
1195 rd_interwiki varchar(32) default NULL,
1196 rd_fragment varchar(255) binary default NULL
1197 ) /*$wgDBTableOptions*/;
1198
1199 CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);
1200
1201
1202 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1203 CREATE TABLE /*_*/querycachetwo (
1204 -- A key name, generally the base name of of the special page.
1205 qcc_type varbinary(32) NOT NULL,
1206
1207 -- Some sort of stored value. Sizes, counts...
1208 qcc_value int unsigned NOT NULL default 0,
1209
1210 -- Target namespace+title
1211 qcc_namespace int NOT NULL default 0,
1212 qcc_title varchar(255) binary NOT NULL default '',
1213
1214 -- Target namespace+title2
1215 qcc_namespacetwo int NOT NULL default 0,
1216 qcc_titletwo varchar(255) binary NOT NULL default ''
1217 ) /*$wgDBTableOptions*/;
1218
1219 CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
1220 CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
1221 CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
1222
1223
1224 -- Used for storing page restrictions (i.e. protection levels)
1225 CREATE TABLE /*_*/page_restrictions (
1226 -- Page to apply restrictions to (Foreign Key to page).
1227 pr_page int NOT NULL,
1228 -- The protection type (edit, move, etc)
1229 pr_type varbinary(60) NOT NULL,
1230 -- The protection level (Sysop, autoconfirmed, etc)
1231 pr_level varbinary(60) NOT NULL,
1232 -- Whether or not to cascade the protection down to pages transcluded.
1233 pr_cascade tinyint NOT NULL,
1234 -- Field for future support of per-user restriction.
1235 pr_user int NULL,
1236 -- Field for time-limited protection.
1237 pr_expiry varbinary(14) NULL,
1238 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1239 pr_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT
1240 ) /*$wgDBTableOptions*/;
1241
1242 CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
1243 CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
1244 CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
1245 CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);
1246
1247
1248 -- Protected titles - nonexistent pages that have been protected
1249 CREATE TABLE /*_*/protected_titles (
1250 pt_namespace int NOT NULL,
1251 pt_title varchar(255) binary NOT NULL,
1252 pt_user int unsigned NOT NULL,
1253 pt_reason tinyblob,
1254 pt_timestamp binary(14) NOT NULL,
1255 pt_expiry varbinary(14) NOT NULL default '',
1256 pt_create_perm varbinary(60) NOT NULL
1257 ) /*$wgDBTableOptions*/;
1258
1259 CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
1260 CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);
1261
1262
1263 -- Name/value pairs indexed by page_id
1264 CREATE TABLE /*_*/page_props (
1265 pp_page int NOT NULL,
1266 pp_propname varbinary(60) NOT NULL,
1267 pp_value blob NOT NULL
1268 ) /*$wgDBTableOptions*/;
1269
1270 CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
1271
1272
1273 -- A table to log updates, one text key row per update.
1274 CREATE TABLE /*_*/updatelog (
1275 ul_key varchar(255) NOT NULL PRIMARY KEY
1276 ) /*$wgDBTableOptions*/;
1277
1278
1279 -- A table to track tags for revisions, logs and recent changes.
1280 CREATE TABLE /*_*/change_tag (
1281 ct_rc_id int NULL,
1282 ct_log_id int NULL,
1283 ct_rev_id int NULL,
1284 ct_tag varchar(255) NOT NULL,
1285 ct_params blob NULL
1286 ) /*$wgDBTableOptions*/;
1287
1288 CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
1289 CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
1290 CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
1291 -- Covering index, so we can pull all the info only out of the index.
1292 CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
1293
1294
1295 -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
1296 -- that only works on MySQL 4.1+
1297 CREATE TABLE /*_*/tag_summary (
1298 ts_rc_id int NULL,
1299 ts_log_id int NULL,
1300 ts_rev_id int NULL,
1301 ts_tags blob NOT NULL
1302 ) /*$wgDBTableOptions*/;
1303
1304 CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
1305 CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
1306 CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);
1307
1308
1309 CREATE TABLE /*_*/valid_tag (
1310 vt_tag varchar(255) NOT NULL PRIMARY KEY
1311 ) /*$wgDBTableOptions*/;
1312
1313 -- vim: sw=2 sts=2 et