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