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