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