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