Merge "Ignore defineProperty() failures in mw.log.deprecate"
[lhc/web/wiklou.git] / maintenance / mssql / tables.sql
1 -- Experimental table definitions for Microsoft SQL Server with
2 -- content-holding fields switched to explicit BINARY charset.
3 -- ------------------------------------------------------------
4
5 -- SQL to create the initial tables for the MediaWiki database.
6 -- This is read and executed by the install script; you should
7 -- not have to run it by itself unless doing a manual install.
8
9 --
10 -- General notes:
11 --
12 -- The comments in this and other files are
13 -- replaced with the defined table prefix by the installer
14 -- and updater scripts. If you are installing or running
15 -- updates manually, you will need to manually insert the
16 -- table prefix if any when running these scripts.
17 --
18
19
20 --
21 -- The user table contains basic account information,
22 -- authentication keys, etc.
23 --
24 -- Some multi-wiki sites may share a single central user table
25 -- between separate wikis using the $wgSharedDB setting.
26 --
27 -- Note that when a external authentication plugin is used,
28 -- user table entries still need to be created to store
29 -- preferences and to key tracking information in the other
30 -- tables.
31
32 -- LINE:53
33 CREATE TABLE /*_*/mwuser (
34 user_id INT NOT NULL PRIMARY KEY IDENTITY(0,1),
35 user_name NVARCHAR(255) NOT NULL UNIQUE DEFAULT '',
36 user_real_name NVARCHAR(255) NOT NULL DEFAULT '',
37 user_password NVARCHAR(255) NOT NULL DEFAULT '',
38 user_newpassword NVARCHAR(255) NOT NULL DEFAULT '',
39 user_newpass_time varchar(14) NULL DEFAULT NULL,
40 user_email NVARCHAR(255) NOT NULL DEFAULT '',
41 user_touched varchar(14) NOT NULL DEFAULT '',
42 user_token NCHAR(32) NOT NULL DEFAULT '',
43 user_email_authenticated varchar(14) DEFAULT NULL,
44 user_email_token NCHAR(32) DEFAULT '',
45 user_email_token_expires varchar(14) DEFAULT NULL,
46 user_registration varchar(14) DEFAULT NULL,
47 user_editcount INT NULL DEFAULT NULL,
48 user_password_expires varchar(14) DEFAULT NULL
49 );
50 CREATE UNIQUE INDEX /*i*/user_name ON /*_*/mwuser (user_name);
51 CREATE INDEX /*i*/user_email_token ON /*_*/mwuser (user_email_token);
52 CREATE INDEX /*i*/user_email ON /*_*/mwuser (user_email);
53
54 -- Insert a dummy user to represent anons
55 INSERT INTO /*_*/mwuser (user_name) VALUES ('##Anonymous##');
56
57 --
58 -- User permissions have been broken out to a separate table;
59 -- this allows sites with a shared user table to have different
60 -- permissions assigned to a user in each project.
61 --
62 -- This table replaces the old user_rights field which used a
63 -- comma-separated nvarchar(max).
64 CREATE TABLE /*_*/user_groups (
65 ug_user INT NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
66 ug_group NVARCHAR(255) NOT NULL DEFAULT '',
67 );
68 CREATE UNIQUE clustered INDEX /*i*/ug_user_group ON /*_*/user_groups (ug_user, ug_group);
69 CREATE INDEX /*i*/ug_group ON /*_*/user_groups(ug_group);
70
71 -- Stores the groups the user has once belonged to.
72 -- The user may still belong to these groups (check user_groups).
73 -- Users are not autopromoted to groups from which they were removed.
74 CREATE TABLE /*_*/user_former_groups (
75 ufg_user INT NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
76 ufg_group nvarchar(255) NOT NULL default ''
77 );
78 CREATE UNIQUE INDEX /*i*/ufg_user_group ON /*_*/user_former_groups (ufg_user,ufg_group);
79
80 -- Stores notifications of user talk page changes, for the display
81 -- of the "you have new messages" box
82 -- Changed user_id column to user_id to avoid clashing with user_id function
83 CREATE TABLE /*_*/user_newtalk (
84 user_id INT NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
85 user_ip NVARCHAR(40) NOT NULL DEFAULT '',
86 user_last_timestamp varchar(14) DEFAULT NULL,
87 );
88 CREATE INDEX /*i*/un_user_id ON /*_*/user_newtalk (user_id);
89 CREATE INDEX /*i*/un_user_ip ON /*_*/user_newtalk (user_ip);
90
91 --
92 -- User preferences and other fun stuff
93 -- replaces old user.user_options nvarchar(max)
94 --
95 CREATE TABLE /*_*/user_properties (
96 up_user INT NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
97 up_property NVARCHAR(255) NOT NULL,
98 up_value NVARCHAR(MAX),
99 );
100 CREATE UNIQUE CLUSTERED INDEX /*i*/user_properties_user_property ON /*_*/user_properties (up_user,up_property);
101 CREATE INDEX /*i*/user_properties_property ON /*_*/user_properties (up_property);
102
103 --
104 -- This table contains a user's bot passwords: passwords that allow access to
105 -- the account via the API with limited rights.
106 --
107 CREATE TABLE /*_*/bot_passwords (
108 bp_user int NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
109 bp_app_id nvarchar(32) NOT NULL,
110 bp_password nvarchar(255) NOT NULL,
111 bp_token nvarchar(255) NOT NULL,
112 bp_restrictions nvarchar(max) NOT NULL,
113 bp_grants nvarchar(max) NOT NULL,
114 PRIMARY KEY (bp_user, bp_app_id)
115 );
116
117
118 --
119 -- Core of the wiki: each page has an entry here which identifies
120 -- it by title and contains some essential metadata.
121 --
122 CREATE TABLE /*_*/page (
123 page_id INT NOT NULL PRIMARY KEY IDENTITY(0,1),
124 page_namespace INT NOT NULL,
125 page_title NVARCHAR(255) NOT NULL,
126 page_restrictions NVARCHAR(255) NOT NULL,
127 page_is_redirect BIT NOT NULL DEFAULT 0,
128 page_is_new BIT NOT NULL DEFAULT 0,
129 page_random real NOT NULL DEFAULT RAND(),
130 page_touched varchar(14) NOT NULL default '',
131 page_links_updated varchar(14) DEFAULT NULL,
132 page_latest INT, -- FK inserted later
133 page_len INT NOT NULL,
134 page_content_model nvarchar(32) default null,
135 page_lang VARBINARY(35) DEFAULT NULL
136 );
137 CREATE UNIQUE INDEX /*i*/name_title ON /*_*/page (page_namespace,page_title);
138 CREATE INDEX /*i*/page_random ON /*_*/page (page_random);
139 CREATE INDEX /*i*/page_len ON /*_*/page (page_len);
140 CREATE INDEX /*i*/page_redirect_namespace_len ON /*_*/page (page_is_redirect, page_namespace, page_len);
141
142 -- insert a dummy page
143 INSERT INTO /*_*/page (page_namespace, page_title, page_restrictions, page_latest, page_len) VALUES (-1,'','',0,0);
144
145 --
146 -- Every edit of a page creates also a revision row.
147 -- This stores metadata about the revision, and a reference
148 -- to the TEXT storage backend.
149 --
150 CREATE TABLE /*_*/revision (
151 rev_id INT NOT NULL UNIQUE IDENTITY(0,1),
152 rev_page INT NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
153 rev_text_id INT NOT NULL, -- FK added later
154 rev_comment NVARCHAR(255) NOT NULL,
155 rev_user INT REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
156 rev_user_text NVARCHAR(255) NOT NULL DEFAULT '',
157 rev_timestamp varchar(14) NOT NULL default '',
158 rev_minor_edit BIT NOT NULL DEFAULT 0,
159 rev_deleted TINYINT NOT NULL DEFAULT 0,
160 rev_len INT,
161 rev_parent_id INT DEFAULT NULL REFERENCES /*_*/revision(rev_id),
162 rev_sha1 nvarchar(32) not null default '',
163 rev_content_model nvarchar(32) default null,
164 rev_content_format nvarchar(64) default null
165 );
166 CREATE UNIQUE CLUSTERED INDEX /*i*/rev_page_id ON /*_*/revision (rev_page, rev_id);
167 CREATE INDEX /*i*/rev_timestamp ON /*_*/revision (rev_timestamp);
168 CREATE INDEX /*i*/page_timestamp ON /*_*/revision (rev_page,rev_timestamp);
169 CREATE INDEX /*i*/user_timestamp ON /*_*/revision (rev_user,rev_timestamp);
170 CREATE INDEX /*i*/usertext_timestamp ON /*_*/revision (rev_user_text,rev_timestamp);
171 CREATE INDEX /*i*/page_user_timestamp ON /*_*/revision (rev_page,rev_user,rev_timestamp);
172
173 -- insert a dummy revision
174 INSERT INTO /*_*/revision (rev_page,rev_text_id,rev_comment,rev_user,rev_len) VALUES (0,0,'',0,0);
175
176 ALTER TABLE /*_*/page ADD CONSTRAINT FK_page_latest_page_id FOREIGN KEY (page_latest) REFERENCES /*_*/revision(rev_id);
177
178 --
179 -- Holds TEXT of individual page revisions.
180 --
181 -- Field names are a holdover from the 'old' revisions table in
182 -- MediaWiki 1.4 and earlier: an upgrade will transform that
183 -- table INTo the 'text' table to minimize unnecessary churning
184 -- and downtime. If upgrading, the other fields will be left unused.
185 CREATE TABLE /*_*/text (
186 old_id INT NOT NULL PRIMARY KEY IDENTITY(0,1),
187 old_text nvarchar(max) NOT NULL,
188 old_flags NVARCHAR(255) NOT NULL,
189 );
190
191 -- insert a dummy text
192 INSERT INTO /*_*/text (old_text,old_flags) VALUES ('','');
193
194 ALTER TABLE /*_*/revision ADD CONSTRAINT FK_rev_text_id_old_id FOREIGN KEY (rev_text_id) REFERENCES /*_*/text(old_id) ON DELETE CASCADE;
195
196 --
197 -- Holding area for deleted articles, which may be viewed
198 -- or restored by admins through the Special:Undelete interface.
199 -- The fields generally correspond to the page, revision, and text
200 -- fields, with several caveats.
201 -- Cannot reasonably create views on this table, due to the presence of TEXT
202 -- columns.
203 CREATE TABLE /*_*/archive (
204 ar_id int NOT NULL PRIMARY KEY IDENTITY,
205 ar_namespace SMALLINT NOT NULL DEFAULT 0,
206 ar_title NVARCHAR(255) NOT NULL DEFAULT '',
207 ar_text NVARCHAR(MAX) NOT NULL,
208 ar_comment NVARCHAR(255) NOT NULL,
209 ar_user INT CONSTRAINT ar_user__user_id__fk FOREIGN KEY REFERENCES /*_*/mwuser(user_id),
210 ar_user_text NVARCHAR(255) NOT NULL,
211 ar_timestamp varchar(14) NOT NULL default '',
212 ar_minor_edit BIT NOT NULL DEFAULT 0,
213 ar_flags NVARCHAR(255) NOT NULL,
214 ar_rev_id INT NULL, -- NOT a FK, the row gets deleted from revision and moved here
215 ar_text_id INT CONSTRAINT ar_text_id__old_id__fk FOREIGN KEY REFERENCES /*_*/text(old_id) ON DELETE CASCADE,
216 ar_deleted TINYINT NOT NULL DEFAULT 0,
217 ar_len INT,
218 ar_page_id INT NULL, -- NOT a FK, the row gets deleted from page and moved here
219 ar_parent_id INT NULL, -- NOT FK
220 ar_sha1 nvarchar(32) default null,
221 ar_content_model nvarchar(32) DEFAULT NULL,
222 ar_content_format nvarchar(64) DEFAULT NULL
223 );
224 CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp);
225 CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp);
226 CREATE INDEX /*i*/ar_revid ON /*_*/archive (ar_rev_id);
227
228
229 --
230 -- Track page-to-page hyperlinks within the wiki.
231 --
232 CREATE TABLE /*_*/pagelinks (
233 pl_from INT NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
234 pl_from_namespace int NOT NULL DEFAULT 0,
235 pl_namespace INT NOT NULL DEFAULT 0,
236 pl_title NVARCHAR(255) NOT NULL DEFAULT '',
237 );
238 CREATE UNIQUE INDEX /*i*/pl_from ON /*_*/pagelinks (pl_from,pl_namespace,pl_title);
239 CREATE UNIQUE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from);
240 CREATE INDEX /*i*/pl_backlinks_namespace ON /*_*/pagelinks (pl_from_namespace,pl_namespace,pl_title,pl_from);
241
242
243 --
244 -- Track template inclusions.
245 --
246 CREATE TABLE /*_*/templatelinks (
247 tl_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
248 tl_from_namespace int NOT NULL default 0,
249 tl_namespace int NOT NULL default 0,
250 tl_title nvarchar(255) NOT NULL default ''
251 );
252
253 CREATE UNIQUE INDEX /*i*/tl_from ON /*_*/templatelinks (tl_from,tl_namespace,tl_title);
254 CREATE UNIQUE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from);
255 CREATE INDEX /*i*/tl_backlinks_namespace ON /*_*/templatelinks (tl_from_namespace,tl_namespace,tl_title,tl_from);
256
257
258 --
259 -- Track links to images *used inline*
260 -- We don't distinguish live from broken links here, so
261 -- they do not need to be changed on upload/removal.
262 --
263 CREATE TABLE /*_*/imagelinks (
264 -- Key to page_id of the page containing the image / media link.
265 il_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
266 il_from_namespace int NOT NULL default 0,
267
268 -- Filename of target image.
269 -- This is also the page_title of the file's description page;
270 -- all such pages are in namespace 6 (NS_FILE).
271 il_to nvarchar(255) NOT NULL default ''
272 );
273
274 CREATE UNIQUE INDEX /*i*/il_from ON /*_*/imagelinks (il_from,il_to);
275 CREATE UNIQUE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from);
276 CREATE INDEX /*i*/il_backlinks_namespace ON /*_*/imagelinks (il_from_namespace,il_to,il_from);
277
278 --
279 -- Track category inclusions *used inline*
280 -- This tracks a single level of category membership
281 --
282 CREATE TABLE /*_*/categorylinks (
283 -- Key to page_id of the page defined as a category member.
284 cl_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
285
286 -- Name of the category.
287 -- This is also the page_title of the category's description page;
288 -- all such pages are in namespace 14 (NS_CATEGORY).
289 cl_to nvarchar(255) NOT NULL default '',
290
291 -- A binary string obtained by applying a sortkey generation algorithm
292 -- (Collation::getSortKey()) to page_title, or cl_sortkey_prefix . "\n"
293 -- . page_title if cl_sortkey_prefix is nonempty.
294 cl_sortkey varbinary(230) NOT NULL default 0x,
295
296 -- A prefix for the raw sortkey manually specified by the user, either via
297 -- [[Category:Foo|prefix]] or {{defaultsort:prefix}}. If nonempty, it's
298 -- concatenated with a line break followed by the page title before the sortkey
299 -- conversion algorithm is run. We store this so that we can update
300 -- collations without reparsing all pages.
301 -- Note: If you change the length of this field, you also need to change
302 -- code in LinksUpdate.php. See bug 25254.
303 cl_sortkey_prefix varbinary(255) NOT NULL default 0x,
304
305 -- This isn't really used at present. Provided for an optional
306 -- sorting method by approximate addition time.
307 cl_timestamp varchar(14) NOT NULL,
308
309 -- Stores $wgCategoryCollation at the time cl_sortkey was generated. This
310 -- can be used to install new collation versions, tracking which rows are not
311 -- yet updated. '' means no collation, this is a legacy row that needs to be
312 -- updated by updateCollation.php. In the future, it might be possible to
313 -- specify different collations per category.
314 cl_collation nvarchar(32) NOT NULL default '',
315
316 -- Stores whether cl_from is a category, file, or other page, so we can
317 -- paginate the three categories separately. This never has to be updated
318 -- after the page is created, since none of these page types can be moved to
319 -- any other.
320 cl_type varchar(10) NOT NULL default 'page',
321 -- SQL server doesn't have enums, so we approximate with this
322 CONSTRAINT cl_type_ckc CHECK (cl_type IN('page', 'subcat', 'file'))
323 );
324
325 CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to);
326
327 -- We always sort within a given category, and within a given type. FIXME:
328 -- Formerly this index didn't cover cl_type (since that didn't exist), so old
329 -- callers won't be using an index: fix this?
330 CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_type,cl_sortkey,cl_from);
331
332 -- Used by the API (and some extensions)
333 CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);
334
335 -- Used when updating collation (e.g. updateCollation.php)
336 CREATE INDEX /*i*/cl_collation_ext ON /*_*/categorylinks (cl_collation, cl_to, cl_type, cl_from);
337
338 --
339 -- Track all existing categories. Something is a category if 1) it has an entry
340 -- somewhere in categorylinks, or 2) it has a description page. Categories
341 -- might not have corresponding pages, so they need to be tracked separately.
342 --
343 CREATE TABLE /*_*/category (
344 -- Primary key
345 cat_id int NOT NULL PRIMARY KEY IDENTITY,
346
347 -- Name of the category, in the same form as page_title (with underscores).
348 -- If there is a category page corresponding to this category, by definition,
349 -- it has this name (in the Category namespace).
350 cat_title nvarchar(255) NOT NULL,
351
352 -- The numbers of member pages (including categories and media), subcatego-
353 -- ries, and Image: namespace members, respectively. These are signed to
354 -- make underflow more obvious. We make the first number include the second
355 -- two for better sorting: subtracting for display is easy, adding for order-
356 -- ing is not.
357 cat_pages int NOT NULL default 0,
358 cat_subcats int NOT NULL default 0,
359 cat_files int NOT NULL default 0
360 );
361
362 CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);
363
364 -- For Special:Mostlinkedcategories
365 CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);
366
367
368 --
369 -- Track links to external URLs
370 --
371 CREATE TABLE /*_*/externallinks (
372 -- Primary key
373 el_id int NOT NULL PRIMARY KEY IDENTITY,
374
375 -- page_id of the referring page
376 el_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
377
378 -- The URL
379 el_to nvarchar(max) NOT NULL,
380
381 -- In the case of HTTP URLs, this is the URL with any username or password
382 -- removed, and with the labels in the hostname reversed and converted to
383 -- lower case. An extra dot is added to allow for matching of either
384 -- example.com or *.example.com in a single scan.
385 -- Example:
386 -- http://user:password@sub.example.com/page.html
387 -- becomes
388 -- http://com.example.sub./page.html
389 -- which allows for fast searching for all pages under example.com with the
390 -- clause:
391 -- WHERE el_index LIKE 'http://com.example.%'
392 el_index nvarchar(450) NOT NULL
393 );
394
395 CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from);
396 CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index);
397 -- el_to index intentionally not added; we cannot index nvarchar(max) columns,
398 -- but we also cannot restrict el_to to a smaller column size as the external
399 -- link may be larger.
400
401 --
402 -- Track interlanguage links
403 --
404 CREATE TABLE /*_*/langlinks (
405 -- page_id of the referring page
406 ll_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
407
408 -- Language code of the target
409 ll_lang nvarchar(20) NOT NULL default '',
410
411 -- Title of the target, including namespace
412 ll_title nvarchar(255) NOT NULL default ''
413 );
414
415 CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang);
416 CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);
417
418
419 --
420 -- Track inline interwiki links
421 --
422 CREATE TABLE /*_*/iwlinks (
423 -- page_id of the referring page
424 iwl_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
425
426 -- Interwiki prefix code of the target
427 iwl_prefix nvarchar(20) NOT NULL default '',
428
429 -- Title of the target, including namespace
430 iwl_title nvarchar(255) NOT NULL default ''
431 );
432
433 CREATE UNIQUE INDEX /*i*/iwl_from ON /*_*/iwlinks (iwl_from, iwl_prefix, iwl_title);
434 CREATE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from);
435 CREATE INDEX /*i*/iwl_prefix_from_title ON /*_*/iwlinks (iwl_prefix, iwl_from, iwl_title);
436
437
438 --
439 -- Contains a single row with some aggregate info
440 -- on the state of the site.
441 --
442 CREATE TABLE /*_*/site_stats (
443 -- The single row should contain 1 here.
444 ss_row_id int NOT NULL,
445
446 -- Total number of edits performed.
447 ss_total_edits bigint default 0,
448
449 -- An approximate count of pages matching the following criteria:
450 -- * in namespace 0
451 -- * not a redirect
452 -- * contains the text '[['
453 -- See Article::isCountable() in includes/Article.php
454 ss_good_articles bigint default 0,
455
456 -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
457 ss_total_pages bigint default '-1',
458
459 -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
460 ss_users bigint default '-1',
461
462 -- Number of users that still edit
463 ss_active_users bigint default '-1',
464
465 -- Number of images, equivalent to SELECT COUNT(*) FROM image
466 ss_images int default 0
467 );
468
469 -- Pointless index to assuage developer superstitions
470 CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id);
471
472
473 --
474 -- The internet is full of jerks, alas. Sometimes it's handy
475 -- to block a vandal or troll account.
476 --
477 CREATE TABLE /*_*/ipblocks (
478 -- Primary key, introduced for privacy.
479 ipb_id int NOT NULL PRIMARY KEY IDENTITY,
480
481 -- Blocked IP address in dotted-quad form or user name.
482 ipb_address nvarchar(255) NOT NULL,
483
484 -- Blocked user ID or 0 for IP blocks.
485 ipb_user int REFERENCES /*_*/mwuser(user_id),
486
487 -- User ID who made the block.
488 ipb_by int REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
489
490 -- User name of blocker
491 ipb_by_text nvarchar(255) NOT NULL default '',
492
493 -- Text comment made by blocker.
494 ipb_reason nvarchar(255) NOT NULL,
495
496 -- Creation (or refresh) date in standard YMDHMS form.
497 -- IP blocks expire automatically.
498 ipb_timestamp varchar(14) NOT NULL default '',
499
500 -- Indicates that the IP address was banned because a banned
501 -- user accessed a page through it. If this is 1, ipb_address
502 -- will be hidden, and the block identified by block ID number.
503 ipb_auto bit NOT NULL default 0,
504
505 -- If set to 1, block applies only to logged-out users
506 ipb_anon_only bit NOT NULL default 0,
507
508 -- Block prevents account creation from matching IP addresses
509 ipb_create_account bit NOT NULL default 1,
510
511 -- Block triggers autoblocks
512 ipb_enable_autoblock bit NOT NULL default 1,
513
514 -- Time at which the block will expire.
515 -- May be "infinity"
516 ipb_expiry varchar(14) NOT NULL,
517
518 -- Start and end of an address range, in hexadecimal
519 -- Size chosen to allow IPv6
520 -- FIXME: these fields were originally blank for single-IP blocks,
521 -- but now they are populated. No migration was ever done. They
522 -- should be fixed to be blank again for such blocks (bug 49504).
523 ipb_range_start varchar(255) NOT NULL,
524 ipb_range_end varchar(255) NOT NULL,
525
526 -- Flag for entries hidden from users and Sysops
527 ipb_deleted bit NOT NULL default 0,
528
529 -- Block prevents user from accessing Special:Emailuser
530 ipb_block_email bit NOT NULL default 0,
531
532 -- Block allows user to edit their own talk page
533 ipb_allow_usertalk bit NOT NULL default 0,
534
535 -- ID of the block that caused this block to exist
536 -- Autoblocks set this to the original block
537 -- so that the original block being deleted also
538 -- deletes the autoblocks
539 ipb_parent_block_id int default NULL REFERENCES /*_*/ipblocks(ipb_id)
540
541 );
542
543 -- Unique index to support "user already blocked" messages
544 -- Any new options which prevent collisions should be included
545 CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address, ipb_user, ipb_auto, ipb_anon_only);
546
547 CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
548 CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start, ipb_range_end);
549 CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
550 CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
551 CREATE INDEX /*i*/ipb_parent_block_id ON /*_*/ipblocks (ipb_parent_block_id);
552
553
554 --
555 -- Uploaded images and other files.
556 --
557 CREATE TABLE /*_*/image (
558 -- Filename.
559 -- This is also the title of the associated description page,
560 -- which will be in namespace 6 (NS_FILE).
561 img_name nvarchar(255) NOT NULL default '' PRIMARY KEY,
562
563 -- File size in bytes.
564 img_size int NOT NULL default 0,
565
566 -- For images, size in pixels.
567 img_width int NOT NULL default 0,
568 img_height int NOT NULL default 0,
569
570 -- Extracted Exif metadata stored as a serialized PHP array.
571 img_metadata varbinary(max) NOT NULL,
572
573 -- For images, bits per pixel if known.
574 img_bits int NOT NULL default 0,
575
576 -- Media type as defined by the MEDIATYPE_xxx constants
577 img_media_type varchar(16) default null,
578
579 -- major part of a MIME media type as defined by IANA
580 -- see http://www.iana.org/assignments/media-types/
581 img_major_mime varchar(16) not null default 'unknown',
582
583 -- minor part of a MIME media type as defined by IANA
584 -- the minor parts are not required to adher to any standard
585 -- but should be consistent throughout the database
586 -- see http://www.iana.org/assignments/media-types/
587 img_minor_mime nvarchar(100) NOT NULL default 'unknown',
588
589 -- Description field as entered by the uploader.
590 -- This is displayed in image upload history and logs.
591 img_description nvarchar(255) NOT NULL,
592
593 -- user_id and user_name of uploader.
594 img_user int REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
595 img_user_text nvarchar(255) NOT NULL,
596
597 -- Time of the upload.
598 img_timestamp nvarchar(14) NOT NULL default '',
599
600 -- SHA-1 content hash in base-36
601 img_sha1 nvarchar(32) NOT NULL default '',
602
603 CONSTRAINT img_major_mime_ckc check (img_major_mime IN('unknown', 'application', 'audio', 'image', 'text', 'video', 'message', 'model', 'multipart', 'chemical')),
604 CONSTRAINT img_media_type_ckc check (img_media_type in('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
605 );
606
607 CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
608 -- Used by Special:ListFiles for sort-by-size
609 CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
610 -- Used by Special:Newimages and Special:ListFiles
611 CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
612 -- Used in API and duplicate search
613 CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1);
614 -- Used to get media of one type
615 CREATE INDEX /*i*/img_media_mime ON /*_*/image (img_media_type,img_major_mime,img_minor_mime);
616
617
618 --
619 -- Previous revisions of uploaded files.
620 -- Awkwardly, image rows have to be moved into
621 -- this table at re-upload time.
622 --
623 CREATE TABLE /*_*/oldimage (
624 -- Base filename: key to image.img_name
625 -- Not a FK because deleting images removes them from image
626 oi_name nvarchar(255) NOT NULL default '',
627
628 -- Filename of the archived file.
629 -- This is generally a timestamp and '!' prepended to the base name.
630 oi_archive_name nvarchar(255) NOT NULL default '',
631
632 -- Other fields as in image...
633 oi_size int NOT NULL default 0,
634 oi_width int NOT NULL default 0,
635 oi_height int NOT NULL default 0,
636 oi_bits int NOT NULL default 0,
637 oi_description nvarchar(255) NOT NULL,
638 oi_user int REFERENCES /*_*/mwuser(user_id),
639 oi_user_text nvarchar(255) NOT NULL,
640 oi_timestamp varchar(14) NOT NULL default '',
641
642 oi_metadata varbinary(max) NOT NULL,
643 oi_media_type varchar(16) default null,
644 oi_major_mime varchar(16) not null default 'unknown',
645 oi_minor_mime nvarchar(100) NOT NULL default 'unknown',
646 oi_deleted tinyint NOT NULL default 0,
647 oi_sha1 nvarchar(32) NOT NULL default '',
648
649 CONSTRAINT oi_major_mime_ckc check (oi_major_mime IN('unknown', 'application', 'audio', 'image', 'text', 'video', 'message', 'model', 'multipart', 'chemical')),
650 CONSTRAINT oi_media_type_ckc check (oi_media_type IN('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
651 );
652
653 CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
654 CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
655 CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name);
656 CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1);
657
658
659 --
660 -- Record of deleted file data
661 --
662 CREATE TABLE /*_*/filearchive (
663 -- Unique row id
664 fa_id int NOT NULL PRIMARY KEY IDENTITY,
665
666 -- Original base filename; key to image.img_name, page.page_title, etc
667 fa_name nvarchar(255) NOT NULL default '',
668
669 -- Filename of archived file, if an old revision
670 fa_archive_name nvarchar(255) default '',
671
672 -- Which storage bin (directory tree or object store) the file data
673 -- is stored in. Should be 'deleted' for files that have been deleted;
674 -- any other bin is not yet in use.
675 fa_storage_group nvarchar(16),
676
677 -- SHA-1 of the file contents plus extension, used as a key for storage.
678 -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
679 --
680 -- If NULL, the file was missing at deletion time or has been purged
681 -- from the archival storage.
682 fa_storage_key nvarchar(64) default '',
683
684 -- Deletion information, if this file is deleted.
685 fa_deleted_user int,
686 fa_deleted_timestamp varchar(14) default '',
687 fa_deleted_reason nvarchar(max),
688
689 -- Duped fields from image
690 fa_size int default 0,
691 fa_width int default 0,
692 fa_height int default 0,
693 fa_metadata varbinary(max),
694 fa_bits int default 0,
695 fa_media_type varchar(16) default null,
696 fa_major_mime varchar(16) not null default 'unknown',
697 fa_minor_mime nvarchar(100) default 'unknown',
698 fa_description nvarchar(255),
699 fa_user int default 0 REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
700 fa_user_text nvarchar(255),
701 fa_timestamp varchar(14) default '',
702
703 -- Visibility of deleted revisions, bitfield
704 fa_deleted tinyint NOT NULL default 0,
705
706 -- sha1 hash of file content
707 fa_sha1 nvarchar(32) NOT NULL default '',
708
709 CONSTRAINT fa_major_mime_ckc check (fa_major_mime in('unknown', 'application', 'audio', 'image', 'text', 'video', 'message', 'model', 'multipart', 'chemical')),
710 CONSTRAINT fa_media_type_ckc check (fa_media_type in('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
711 );
712
713 -- pick out by image name
714 CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
715 -- pick out dupe files
716 CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
717 -- sort by deletion time
718 CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
719 -- sort by uploader
720 CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
721 -- find file by sha1, 10 bytes will be enough for hashes to be indexed
722 CREATE INDEX /*i*/fa_sha1 ON /*_*/filearchive (fa_sha1);
723
724
725 --
726 -- Store information about newly uploaded files before they're
727 -- moved into the actual filestore
728 --
729 CREATE TABLE /*_*/uploadstash (
730 us_id int NOT NULL PRIMARY KEY IDENTITY,
731
732 -- the user who uploaded the file.
733 us_user int REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
734
735 -- file key. this is how applications actually search for the file.
736 -- this might go away, or become the primary key.
737 us_key nvarchar(255) NOT NULL,
738
739 -- the original path
740 us_orig_path nvarchar(255) NOT NULL,
741
742 -- the temporary path at which the file is actually stored
743 us_path nvarchar(255) NOT NULL,
744
745 -- which type of upload the file came from (sometimes)
746 us_source_type nvarchar(50),
747
748 -- the date/time on which the file was added
749 us_timestamp varchar(14) NOT NULL,
750
751 us_status nvarchar(50) NOT NULL,
752
753 -- chunk counter starts at 0, current offset is stored in us_size
754 us_chunk_inx int NULL,
755
756 -- Serialized file properties from FSFile::getProps()
757 us_props nvarchar(max),
758
759 -- file size in bytes
760 us_size int NOT NULL,
761 -- this hash comes from FSFile::getSha1Base36(), and is 31 characters
762 us_sha1 nvarchar(31) NOT NULL,
763 us_mime nvarchar(255),
764 -- Media type as defined by the MEDIATYPE_xxx constants, should duplicate definition in the image table
765 us_media_type varchar(16) default null,
766 -- image-specific properties
767 us_image_width int,
768 us_image_height int,
769 us_image_bits smallint,
770
771 CONSTRAINT us_media_type_ckc check (us_media_type in('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
772 );
773
774 -- sometimes there's a delete for all of a user's stuff.
775 CREATE INDEX /*i*/us_user ON /*_*/uploadstash (us_user);
776 -- pick out files by key, enforce key uniqueness
777 CREATE UNIQUE INDEX /*i*/us_key ON /*_*/uploadstash (us_key);
778 -- the abandoned upload cleanup script needs this
779 CREATE INDEX /*i*/us_timestamp ON /*_*/uploadstash (us_timestamp);
780
781
782 --
783 -- Primarily a summary table for Special:Recentchanges,
784 -- this table contains some additional info on edits from
785 -- the last few days, see Article::editUpdates()
786 --
787 CREATE TABLE /*_*/recentchanges (
788 rc_id int NOT NULL CONSTRAINT recentchanges__pk PRIMARY KEY IDENTITY,
789 rc_timestamp varchar(14) not null default '',
790
791 -- As in revision
792 rc_user int NOT NULL default 0 CONSTRAINT rc_user__user_id__fk FOREIGN KEY REFERENCES /*_*/mwuser(user_id),
793 rc_user_text nvarchar(255) NOT NULL,
794
795 -- When pages are renamed, their RC entries do _not_ change.
796 rc_namespace int NOT NULL default 0,
797 rc_title nvarchar(255) NOT NULL default '',
798
799 -- as in revision...
800 rc_comment nvarchar(255) NOT NULL default '',
801 rc_minor bit NOT NULL default 0,
802
803 -- Edits by user accounts with the 'bot' rights key are
804 -- marked with a 1 here, and will be hidden from the
805 -- default view.
806 rc_bot bit NOT NULL default 0,
807
808 -- Set if this change corresponds to a page creation
809 rc_new bit NOT NULL default 0,
810
811 -- Key to page_id (was cur_id prior to 1.5).
812 -- This will keep links working after moves while
813 -- retaining the at-the-time name in the changes list.
814 rc_cur_id int, -- NOT FK
815
816 -- rev_id of the given revision
817 rc_this_oldid int, -- NOT FK
818
819 -- rev_id of the prior revision, for generating diff links.
820 rc_last_oldid int, -- NOT FK
821
822 -- The type of change entry (RC_EDIT,RC_NEW,RC_LOG,RC_EXTERNAL)
823 rc_type tinyint NOT NULL default 0,
824
825 -- The source of the change entry (replaces rc_type)
826 -- default of '' is temporary, needed for initial migration
827 rc_source nvarchar(16) not null default '',
828
829 -- If the Recent Changes Patrol option is enabled,
830 -- users may mark edits as having been reviewed to
831 -- remove a warning flag on the RC list.
832 -- A value of 1 indicates the page has been reviewed.
833 rc_patrolled bit NOT NULL default 0,
834
835 -- Recorded IP address the edit was made from, if the
836 -- $wgPutIPinRC option is enabled.
837 rc_ip nvarchar(40) NOT NULL default '',
838
839 -- Text length in characters before
840 -- and after the edit
841 rc_old_len int,
842 rc_new_len int,
843
844 -- Visibility of recent changes items, bitfield
845 rc_deleted tinyint NOT NULL default 0,
846
847 -- Value corresponding to log_id, specific log entries
848 rc_logid int, -- FK added later
849 -- Store log type info here, or null
850 rc_log_type nvarchar(255) NULL default NULL,
851 -- Store log action or null
852 rc_log_action nvarchar(255) NULL default NULL,
853 -- Log params
854 rc_params nvarchar(max) NULL
855 );
856
857 CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
858 CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
859 CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
860 CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
861 CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
862 CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
863 CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);
864 CREATE INDEX /*i*/rc_name_type_patrolled_timestamp ON /*_*/recentchanges (rc_namespace, rc_type, rc_patrolled, rc_timestamp);
865
866
867 CREATE TABLE /*_*/watchlist (
868 wl_id int NOT NULL PRIMARY KEY IDENTITY,
869 -- Key to user.user_id
870 wl_user int NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
871
872 -- Key to page_namespace/page_title
873 -- Note that users may watch pages which do not exist yet,
874 -- or existed in the past but have been deleted.
875 wl_namespace int NOT NULL default 0,
876 wl_title nvarchar(255) NOT NULL default '',
877
878 -- Timestamp used to send notification e-mails and show "updated since last visit" markers on
879 -- history and recent changes / watchlist. Set to NULL when the user visits the latest revision
880 -- of the page, which means that they should be sent an e-mail on the next change.
881 wl_notificationtimestamp varchar(14)
882
883 );
884
885 CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
886 CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);
887
888
889 --
890 -- Our search index for the builtin MediaWiki search
891 --
892 CREATE TABLE /*_*/searchindex (
893 -- Key to page_id
894 si_page int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
895
896 -- Munged version of title
897 si_title nvarchar(255) NOT NULL default '',
898
899 -- Munged version of body text
900 si_text nvarchar(max) NOT NULL
901 );
902
903 CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
904 -- Fulltext index is defined in MssqlInstaller.php
905
906 --
907 -- Recognized interwiki link prefixes
908 --
909 CREATE TABLE /*_*/interwiki (
910 -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
911 iw_prefix nvarchar(32) NOT NULL,
912
913 -- The URL of the wiki, with "$1" as a placeholder for an article name.
914 -- Any spaces in the name will be transformed to underscores before
915 -- insertion.
916 iw_url nvarchar(max) NOT NULL,
917
918 -- The URL of the file api.php
919 iw_api nvarchar(max) NOT NULL,
920
921 -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' ))
922 iw_wikiid nvarchar(64) NOT NULL,
923
924 -- A boolean value indicating whether the wiki is in this project
925 -- (used, for example, to detect redirect loops)
926 iw_local bit NOT NULL,
927
928 -- Boolean value indicating whether interwiki transclusions are allowed.
929 iw_trans bit NOT NULL default 0
930 );
931
932 CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);
933
934
935 --
936 -- Used for caching expensive grouped queries
937 --
938 CREATE TABLE /*_*/querycache (
939 -- A key name, generally the base name of of the special page.
940 qc_type nvarchar(32) NOT NULL,
941
942 -- Some sort of stored value. Sizes, counts...
943 qc_value int NOT NULL default 0,
944
945 -- Target namespace+title
946 qc_namespace int NOT NULL default 0,
947 qc_title nvarchar(255) NOT NULL default ''
948 );
949
950 CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);
951
952
953 --
954 -- For a few generic cache operations if not using Memcached
955 --
956 CREATE TABLE /*_*/objectcache (
957 keyname nvarchar(255) NOT NULL default '' PRIMARY KEY,
958 value varbinary(max),
959 exptime varchar(14)
960 );
961 CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);
962
963
964 --
965 -- Cache of interwiki transclusion
966 --
967 CREATE TABLE /*_*/transcache (
968 tc_url nvarchar(255) NOT NULL,
969 tc_contents nvarchar(max),
970 tc_time varchar(14) NOT NULL
971 );
972
973 CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url);
974
975
976 CREATE TABLE /*_*/logging (
977 -- Log ID, for referring to this specific log entry, probably for deletion and such.
978 log_id int NOT NULL PRIMARY KEY IDENTITY(0,1),
979
980 -- Symbolic keys for the general log type and the action type
981 -- within the log. The output format will be controlled by the
982 -- action field, but only the type controls categorization.
983 log_type nvarchar(32) NOT NULL default '',
984 log_action nvarchar(32) NOT NULL default '',
985
986 -- Timestamp. Duh.
987 log_timestamp varchar(14) NOT NULL default '',
988
989 -- The user who performed this action; key to user_id
990 log_user int, -- NOT an FK, if a user is deleted we still want to maintain a record of who did a thing
991
992 -- Name of the user who performed this action
993 log_user_text nvarchar(255) NOT NULL default '',
994
995 -- Key to the page affected. Where a user is the target,
996 -- this will point to the user page.
997 log_namespace int NOT NULL default 0,
998 log_title nvarchar(255) NOT NULL default '',
999 log_page int NULL, -- NOT an FK, logging entries are inserted for deleted pages which still reference the deleted page ids
1000
1001 -- Freeform text. Interpreted as edit history comments.
1002 log_comment nvarchar(255) NOT NULL default '',
1003
1004 -- miscellaneous parameters:
1005 -- LF separated list (old system) or serialized PHP array (new system)
1006 log_params nvarchar(max) NOT NULL,
1007
1008 -- rev_deleted for logs
1009 log_deleted tinyint NOT NULL default 0
1010 );
1011
1012 CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
1013 CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
1014 CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
1015 CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
1016 CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp);
1017 CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp);
1018 CREATE INDEX /*i*/type_action ON /*_*/logging (log_type, log_action, log_timestamp);
1019 CREATE INDEX /*i*/log_user_text_type_time ON /*_*/logging (log_user_text, log_type, log_timestamp);
1020 CREATE INDEX /*i*/log_user_text_time ON /*_*/logging (log_user_text, log_timestamp);
1021
1022 INSERT INTO /*_*/logging (log_user,log_page,log_params) VALUES(0,0,'');
1023
1024 ALTER TABLE /*_*/recentchanges ADD CONSTRAINT rc_logid__log_id__fk FOREIGN KEY (rc_logid) REFERENCES /*_*/logging(log_id) ON DELETE CASCADE;
1025
1026 CREATE TABLE /*_*/log_search (
1027 -- The type of ID (rev ID, log ID, rev timestamp, username)
1028 ls_field nvarchar(32) NOT NULL,
1029 -- The value of the ID
1030 ls_value nvarchar(255) NOT NULL,
1031 -- Key to log_id
1032 ls_log_id int REFERENCES /*_*/logging(log_id) ON DELETE CASCADE
1033 );
1034 CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id);
1035 CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);
1036
1037
1038 -- Jobs performed by parallel apache threads or a command-line daemon
1039 CREATE TABLE /*_*/job (
1040 job_id int NOT NULL PRIMARY KEY IDENTITY,
1041
1042 -- Command name
1043 -- Limited to 60 to prevent key length overflow
1044 job_cmd nvarchar(60) NOT NULL default '',
1045
1046 -- Namespace and title to act on
1047 -- Should be 0 and '' if the command does not operate on a title
1048 job_namespace int NOT NULL,
1049 job_title nvarchar(255) NOT NULL,
1050
1051 -- Timestamp of when the job was inserted
1052 -- NULL for jobs added before addition of the timestamp
1053 job_timestamp nvarchar(14) NULL default NULL,
1054
1055 -- Any other parameters to the command
1056 -- Stored as a PHP serialized array, or an empty string if there are no parameters
1057 job_params nvarchar(max) NOT NULL,
1058
1059 -- Random, non-unique, number used for job acquisition (for lock concurrency)
1060 job_random int NOT NULL default 0,
1061
1062 -- The number of times this job has been locked
1063 job_attempts int NOT NULL default 0,
1064
1065 -- Field that conveys process locks on rows via process UUIDs
1066 job_token nvarchar(32) NOT NULL default '',
1067
1068 -- Timestamp when the job was locked
1069 job_token_timestamp varchar(14) NULL default NULL,
1070
1071 -- Base 36 SHA1 of the job parameters relevant to detecting duplicates
1072 job_sha1 nvarchar(32) NOT NULL default ''
1073 );
1074
1075 CREATE INDEX /*i*/job_sha1 ON /*_*/job (job_sha1);
1076 CREATE INDEX /*i*/job_cmd_token ON /*_*/job (job_cmd,job_token,job_random);
1077 CREATE INDEX /*i*/job_cmd_token_id ON /*_*/job (job_cmd,job_token,job_id);
1078 CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title);
1079 CREATE INDEX /*i*/job_timestamp ON /*_*/job (job_timestamp);
1080
1081
1082 -- Details of updates to cached special pages
1083 CREATE TABLE /*_*/querycache_info (
1084 -- Special page name
1085 -- Corresponds to a qc_type value
1086 qci_type nvarchar(32) NOT NULL default '',
1087
1088 -- Timestamp of last update
1089 qci_timestamp varchar(14) NOT NULL default ''
1090 );
1091
1092 CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type);
1093
1094
1095 -- For each redirect, this table contains exactly one row defining its target
1096 CREATE TABLE /*_*/redirect (
1097 -- Key to the page_id of the redirect page
1098 rd_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
1099
1100 -- Key to page_namespace/page_title of the target page.
1101 -- The target page may or may not exist, and due to renames
1102 -- and deletions may refer to different page records as time
1103 -- goes by.
1104 rd_namespace int NOT NULL default 0,
1105 rd_title nvarchar(255) NOT NULL default '',
1106 rd_interwiki nvarchar(32) default NULL,
1107 rd_fragment nvarchar(255) default NULL
1108 );
1109
1110 CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);
1111
1112
1113 -- Used for caching expensive grouped queries that need two links (for example double-redirects)
1114 CREATE TABLE /*_*/querycachetwo (
1115 -- A key name, generally the base name of of the special page.
1116 qcc_type nvarchar(32) NOT NULL,
1117
1118 -- Some sort of stored value. Sizes, counts...
1119 qcc_value int NOT NULL default 0,
1120
1121 -- Target namespace+title
1122 qcc_namespace int NOT NULL default 0,
1123 qcc_title nvarchar(255) NOT NULL default '',
1124
1125 -- Target namespace+title2
1126 qcc_namespacetwo int NOT NULL default 0,
1127 qcc_titletwo nvarchar(255) NOT NULL default ''
1128 );
1129
1130 CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
1131 CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
1132 CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
1133
1134
1135 -- Used for storing page restrictions (i.e. protection levels)
1136 CREATE TABLE /*_*/page_restrictions (
1137 -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
1138 pr_id int NOT NULL PRIMARY KEY IDENTITY,
1139 -- Page to apply restrictions to (Foreign Key to page).
1140 pr_page int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
1141 -- The protection type (edit, move, etc)
1142 pr_type nvarchar(60) NOT NULL,
1143 -- The protection level (Sysop, autoconfirmed, etc)
1144 pr_level nvarchar(60) NOT NULL,
1145 -- Whether or not to cascade the protection down to pages transcluded.
1146 pr_cascade bit NOT NULL,
1147 -- Field for future support of per-user restriction.
1148 pr_user int NULL,
1149 -- Field for time-limited protection.
1150 pr_expiry varchar(14) NULL
1151 );
1152
1153 CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
1154 CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
1155 CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
1156 CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);
1157
1158
1159 -- Protected titles - nonexistent pages that have been protected
1160 CREATE TABLE /*_*/protected_titles (
1161 pt_namespace int NOT NULL,
1162 pt_title nvarchar(255) NOT NULL,
1163 pt_user int REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
1164 pt_reason nvarchar(255),
1165 pt_timestamp varchar(14) NOT NULL,
1166 pt_expiry varchar(14) NOT NULL,
1167 pt_create_perm nvarchar(60) NOT NULL
1168 );
1169
1170 CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
1171 CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);
1172
1173
1174 -- Name/value pairs indexed by page_id
1175 CREATE TABLE /*_*/page_props (
1176 pp_page int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
1177 pp_propname nvarchar(60) NOT NULL,
1178 pp_value nvarchar(max) NOT NULL,
1179 pp_sortkey float DEFAULT NULL
1180 );
1181
1182 CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
1183 CREATE UNIQUE INDEX /*i*/pp_propname_page ON /*_*/page_props (pp_propname,pp_page);
1184 CREATE UNIQUE INDEX /*i*/pp_propname_sortkey_page ON /*_*/page_props (pp_propname,pp_sortkey,pp_page);
1185
1186
1187 -- A table to log updates, one text key row per update.
1188 CREATE TABLE /*_*/updatelog (
1189 ul_key nvarchar(255) NOT NULL PRIMARY KEY,
1190 ul_value nvarchar(max)
1191 );
1192
1193
1194 -- A table to track tags for revisions, logs and recent changes.
1195 CREATE TABLE /*_*/change_tag (
1196 ct_id int NOT NULL PRIMARY KEY IDENTITY,
1197 -- RCID for the change
1198 ct_rc_id int NULL REFERENCES /*_*/recentchanges(rc_id),
1199 -- LOGID for the change
1200 ct_log_id int NULL REFERENCES /*_*/logging(log_id),
1201 -- REVID for the change
1202 ct_rev_id int NULL REFERENCES /*_*/revision(rev_id),
1203 -- Tag applied
1204 ct_tag nvarchar(255) NOT NULL,
1205 -- Parameters for the tag, presently unused
1206 ct_params nvarchar(max) NULL
1207 );
1208
1209 CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
1210 CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
1211 CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
1212 -- Covering index, so we can pull all the info only out of the index.
1213 CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
1214
1215
1216 -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
1217 -- that only works on MySQL 4.1+
1218 CREATE TABLE /*_*/tag_summary (
1219 ts_id int NOT NULL PRIMARY KEY IDENTITY,
1220 -- RCID for the change
1221 ts_rc_id int NULL REFERENCES /*_*/recentchanges(rc_id),
1222 -- LOGID for the change
1223 ts_log_id int NULL REFERENCES /*_*/logging(log_id),
1224 -- REVID for the change
1225 ts_rev_id int NULL REFERENCES /*_*/revision(rev_id),
1226 -- Comma-separated list of tags
1227 ts_tags nvarchar(max) NOT NULL
1228 );
1229
1230 CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
1231 CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
1232 CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);
1233
1234
1235 CREATE TABLE /*_*/valid_tag (
1236 vt_tag nvarchar(255) NOT NULL PRIMARY KEY
1237 );
1238
1239 -- Table for storing localisation data
1240 CREATE TABLE /*_*/l10n_cache (
1241 -- Language code
1242 lc_lang nvarchar(32) NOT NULL,
1243 -- Cache key
1244 lc_key nvarchar(255) NOT NULL,
1245 -- Value
1246 lc_value varbinary(max) NOT NULL
1247 );
1248 CREATE INDEX /*i*/lc_lang_key ON /*_*/l10n_cache (lc_lang, lc_key);
1249
1250 -- Table caching which local files a module depends on that aren't
1251 -- registered directly, used for fast retrieval of file dependency.
1252 -- Currently only used for tracking images that CSS depends on
1253 CREATE TABLE /*_*/module_deps (
1254 -- Module name
1255 md_module nvarchar(255) NOT NULL,
1256 -- Skin name
1257 md_skin nvarchar(32) NOT NULL,
1258 -- JSON nvarchar(max) with file dependencies
1259 md_deps nvarchar(max) NOT NULL
1260 );
1261 CREATE UNIQUE INDEX /*i*/md_module_skin ON /*_*/module_deps (md_module, md_skin);
1262
1263 -- Holds all the sites known to the wiki.
1264 CREATE TABLE /*_*/sites (
1265 -- Numeric id of the site
1266 site_id int NOT NULL PRIMARY KEY IDENTITY,
1267
1268 -- Global identifier for the site, ie 'enwiktionary'
1269 site_global_key nvarchar(32) NOT NULL,
1270
1271 -- Type of the site, ie 'mediawiki'
1272 site_type nvarchar(32) NOT NULL,
1273
1274 -- Group of the site, ie 'wikipedia'
1275 site_group nvarchar(32) NOT NULL,
1276
1277 -- Source of the site data, ie 'local', 'wikidata', 'my-magical-repo'
1278 site_source nvarchar(32) NOT NULL,
1279
1280 -- Language code of the sites primary language.
1281 site_language nvarchar(32) NOT NULL,
1282
1283 -- Protocol of the site, ie 'http://', 'irc://', '//'
1284 -- This field is an index for lookups and is build from type specific data in site_data.
1285 site_protocol nvarchar(32) NOT NULL,
1286
1287 -- Domain of the site in reverse order, ie 'org.mediawiki.www.'
1288 -- This field is an index for lookups and is build from type specific data in site_data.
1289 site_domain NVARCHAR(255) NOT NULL,
1290
1291 -- Type dependent site data.
1292 site_data nvarchar(max) NOT NULL,
1293
1294 -- If site.tld/path/key:pageTitle should forward users to the page on
1295 -- the actual site, where "key" is the local identifier.
1296 site_forward bit NOT NULL,
1297
1298 -- Type dependent site config.
1299 -- For instance if template transclusion should be allowed if it's a MediaWiki.
1300 site_config nvarchar(max) NOT NULL
1301 );
1302
1303 CREATE UNIQUE INDEX /*i*/sites_global_key ON /*_*/sites (site_global_key);
1304 CREATE INDEX /*i*/sites_type ON /*_*/sites (site_type);
1305 CREATE INDEX /*i*/sites_group ON /*_*/sites (site_group);
1306 CREATE INDEX /*i*/sites_source ON /*_*/sites (site_source);
1307 CREATE INDEX /*i*/sites_language ON /*_*/sites (site_language);
1308 CREATE INDEX /*i*/sites_protocol ON /*_*/sites (site_protocol);
1309 CREATE INDEX /*i*/sites_domain ON /*_*/sites (site_domain);
1310 CREATE INDEX /*i*/sites_forward ON /*_*/sites (site_forward);
1311
1312 -- Links local site identifiers to their corresponding site.
1313 CREATE TABLE /*_*/site_identifiers (
1314 -- Key on site.site_id
1315 si_site int NOT NULL REFERENCES /*_*/sites(site_id) ON DELETE CASCADE,
1316
1317 -- local key type, ie 'interwiki' or 'langlink'
1318 si_type nvarchar(32) NOT NULL,
1319
1320 -- local key value, ie 'en' or 'wiktionary'
1321 si_key nvarchar(32) NOT NULL
1322 );
1323
1324 CREATE UNIQUE INDEX /*i*/site_ids_type ON /*_*/site_identifiers (si_type, si_key);
1325 CREATE INDEX /*i*/site_ids_site ON /*_*/site_identifiers (si_site);
1326 CREATE INDEX /*i*/site_ids_key ON /*_*/site_identifiers (si_key);