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