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