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