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