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