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