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