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