summaryrefslogtreecommitdiff
path: root/maintenance/mssql/tables.sql
blob: 5b09ffdc01e882f3ddb591d7d0014b482abb5a47 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
-- Experimental table definitions for Microsoft SQL Server with
-- content-holding fields switched to explicit BINARY charset.
-- ------------------------------------------------------------

-- SQL to create the initial tables for the MediaWiki database.
-- This is read and executed by the install script; you should
-- not have to run it by itself unless doing a manual install.

--
-- General notes:
--
-- The comments in this and other files are
-- replaced with the defined table prefix by the installer
-- and updater scripts. If you are installing or running
-- updates manually, you will need to manually insert the
-- table prefix if any when running these scripts.
--


--
-- The user table contains basic account information,
-- authentication keys, etc.
--
-- Some multi-wiki sites may share a single central user table
-- between separate wikis using the $wgSharedDB setting.
--
-- Note that when a external authentication plugin is used,
-- user table entries still need to be created to store
-- preferences and to key tracking information in the other
-- tables.

-- LINE:53
CREATE TABLE /*_*/mwuser (
   user_id           INT           NOT NULL  PRIMARY KEY IDENTITY(0,1),
   user_name         NVARCHAR(255)  NOT NULL UNIQUE DEFAULT '',
   user_real_name    NVARCHAR(255)  NOT NULL DEFAULT '',
   user_password     NVARCHAR(255)  NOT NULL DEFAULT '',
   user_newpassword  NVARCHAR(255)  NOT NULL DEFAULT '',
   user_newpass_time varchar(14) NULL DEFAULT NULL,
   user_email        NVARCHAR(255)  NOT NULL DEFAULT '',
   user_options      NVARCHAR(MAX) NOT NULL DEFAULT '',
   user_touched      varchar(14)      NOT NULL DEFAULT '',
   user_token        NCHAR(32)      NOT NULL DEFAULT '',
   user_email_authenticated varchar(14) DEFAULT NULL,
   user_email_token  NCHAR(32) DEFAULT '',
   user_email_token_expires varchar(14) DEFAULT NULL,
   user_registration varchar(14) DEFAULT NULL,
   user_editcount    INT NULL DEFAULT NULL,
   user_password_expires varchar(14) DEFAULT NULL
);
CREATE UNIQUE INDEX /*i*/user_name ON /*_*/mwuser (user_name);
CREATE INDEX /*i*/user_email_token ON /*_*/mwuser (user_email_token);
CREATE INDEX /*i*/user_email ON /*_*/mwuser (user_email);

-- Insert a dummy user to represent anons
INSERT INTO /*_*/mwuser (user_name) VALUES ('##Anonymous##');

--
-- User permissions have been broken out to a separate table;
-- this allows sites with a shared user table to have different
-- permissions assigned to a user in each project.
--
-- This table replaces the old user_rights field which used a
-- comma-separated nvarchar(max).
CREATE TABLE /*_*/user_groups (
   ug_user  INT     NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
   ug_group NVARCHAR(255) NOT NULL DEFAULT '',
);
CREATE UNIQUE clustered INDEX /*i*/ug_user_group ON /*_*/user_groups (ug_user, ug_group);
CREATE INDEX /*i*/ug_group ON /*_*/user_groups(ug_group);

-- Stores the groups the user has once belonged to.
-- The user may still belong to these groups (check user_groups).
-- Users are not autopromoted to groups from which they were removed.
CREATE TABLE /*_*/user_former_groups (
  ufg_user INT NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
  ufg_group nvarchar(255) NOT NULL default ''
);
CREATE UNIQUE INDEX /*i*/ufg_user_group ON /*_*/user_former_groups (ufg_user,ufg_group);

-- Stores notifications of user talk page changes, for the display
-- of the "you have new messages" box
-- Changed user_id column to user_id to avoid clashing with user_id function
CREATE TABLE /*_*/user_newtalk (
   user_id INT         NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
   user_ip NVARCHAR(40) NOT NULL DEFAULT '',
   user_last_timestamp varchar(14) DEFAULT NULL,
);
CREATE INDEX /*i*/un_user_id ON /*_*/user_newtalk (user_id);
CREATE INDEX /*i*/un_user_ip ON /*_*/user_newtalk (user_ip);

--
-- User preferences and other fun stuff
-- replaces old user.user_options nvarchar(max)
--
CREATE TABLE /*_*/user_properties (
	up_user INT NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,
	up_property NVARCHAR(255) NOT NULL,
	up_value NVARCHAR(MAX),
);
CREATE UNIQUE CLUSTERED INDEX /*i*/user_properties_user_property ON /*_*/user_properties (up_user,up_property);
CREATE INDEX /*i*/user_properties_property ON /*_*/user_properties (up_property);


--
-- Core of the wiki: each page has an entry here which identifies
-- it by title and contains some essential metadata.
--
CREATE TABLE /*_*/page (
   page_id        INT          NOT NULL  PRIMARY KEY IDENTITY(0,1),
   page_namespace INT          NOT NULL,
   page_title     NVARCHAR(255)  NOT NULL,
   page_restrictions NVARCHAR(255) NOT NULL,
   page_is_redirect BIT           NOT NULL DEFAULT 0,
   page_is_new BIT                NOT NULL DEFAULT 0,
   page_random real     NOT NULL DEFAULT RAND(),
   page_touched varchar(14) NOT NULL default '',
   page_links_updated varchar(14) DEFAULT NULL,
   page_latest INT, -- FK inserted later
   page_len INT NOT NULL,
   page_content_model nvarchar(32) default null,
   page_lang VARBINARY(35) DEFAULT NULL
);
CREATE UNIQUE INDEX /*i*/name_title ON /*_*/page (page_namespace,page_title);
CREATE INDEX /*i*/page_random ON /*_*/page (page_random);
CREATE INDEX /*i*/page_len ON /*_*/page (page_len);
CREATE INDEX /*i*/page_redirect_namespace_len ON /*_*/page (page_is_redirect, page_namespace, page_len);

-- insert a dummy page
INSERT INTO /*_*/page (page_namespace, page_title, page_restrictions, page_latest, page_len) VALUES (-1,'','',0,0);

--
-- Every edit of a page creates also a revision row.
-- This stores metadata about the revision, and a reference
-- to the TEXT storage backend.
--
CREATE TABLE /*_*/revision (
   rev_id INT NOT NULL UNIQUE IDENTITY(0,1),
   rev_page INT NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
   rev_text_id INT  NOT NULL, -- FK added later
   rev_comment NVARCHAR(255) NOT NULL,
   rev_user INT REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
   rev_user_text NVARCHAR(255) NOT NULL DEFAULT '',
   rev_timestamp varchar(14) NOT NULL default '',
   rev_minor_edit BIT NOT NULL DEFAULT 0,
   rev_deleted TINYINT  NOT NULL DEFAULT 0,
   rev_len INT,
   rev_parent_id INT DEFAULT NULL REFERENCES /*_*/revision(rev_id),
   rev_sha1 nvarchar(32) not null default '',
   rev_content_model nvarchar(32) default null,
   rev_content_format nvarchar(64) default null
);
CREATE UNIQUE CLUSTERED INDEX /*i*/rev_page_id ON /*_*/revision (rev_page, rev_id);
CREATE INDEX /*i*/rev_timestamp ON /*_*/revision (rev_timestamp);
CREATE INDEX /*i*/page_timestamp ON /*_*/revision (rev_page,rev_timestamp);
CREATE INDEX /*i*/user_timestamp ON /*_*/revision (rev_user,rev_timestamp);
CREATE INDEX /*i*/usertext_timestamp ON /*_*/revision (rev_user_text,rev_timestamp);
CREATE INDEX /*i*/page_user_timestamp ON /*_*/revision (rev_page,rev_user,rev_timestamp);

-- insert a dummy revision
INSERT INTO /*_*/revision (rev_page,rev_text_id,rev_comment,rev_user,rev_len) VALUES (0,0,'',0,0);

ALTER TABLE /*_*/page ADD CONSTRAINT FK_page_latest_page_id FOREIGN KEY (page_latest) REFERENCES /*_*/revision(rev_id);

--
-- Holds TEXT of individual page revisions.
--
-- Field names are a holdover from the 'old' revisions table in
-- MediaWiki 1.4 and earlier: an upgrade will transform that
-- table INTo the 'text' table to minimize unnecessary churning
-- and downtime. If upgrading, the other fields will be left unused.
CREATE TABLE /*_*/text (
   old_id INT NOT NULL  PRIMARY KEY IDENTITY(0,1),
   old_text nvarchar(max) NOT NULL,
   old_flags NVARCHAR(255) NOT NULL,
);

-- insert a dummy text
INSERT INTO /*_*/text (old_text,old_flags) VALUES ('','');

ALTER TABLE /*_*/revision ADD CONSTRAINT FK_rev_text_id_old_id FOREIGN KEY (rev_text_id) REFERENCES /*_*/text(old_id) ON DELETE CASCADE;

--
-- Holding area for deleted articles, which may be viewed
-- or restored by admins through the Special:Undelete interface.
-- The fields generally correspond to the page, revision, and text
-- fields, with several caveats.
-- Cannot reasonably create views on this table, due to the presence of TEXT
-- columns.
CREATE TABLE /*_*/archive (
   ar_id int NOT NULL PRIMARY KEY IDENTITY,
   ar_namespace SMALLINT NOT NULL DEFAULT 0,
   ar_title NVARCHAR(255) NOT NULL DEFAULT '',
   ar_text NVARCHAR(MAX) NOT NULL,
   ar_comment NVARCHAR(255) NOT NULL,
   ar_user INT REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
   ar_user_text NVARCHAR(255) NOT NULL,
   ar_timestamp varchar(14) NOT NULL default '',
   ar_minor_edit BIT NOT NULL DEFAULT 0,
   ar_flags NVARCHAR(255) NOT NULL,
   ar_rev_id INT NULL, -- NOT a FK, the row gets deleted from revision and moved here
   ar_text_id INT REFERENCES /*_*/text(old_id) ON DELETE CASCADE,
   ar_deleted TINYINT NOT NULL DEFAULT 0,
   ar_len INT,
   ar_page_id INT NULL, -- NOT a FK, the row gets deleted from page and moved here
   ar_parent_id INT NULL REFERENCES /*_*/revision(rev_id),
   ar_sha1 nvarchar(32) default null,
   ar_content_model nvarchar(32) DEFAULT NULL,
  ar_content_format nvarchar(64) DEFAULT NULL
);
CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp);
CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp);
CREATE INDEX /*i*/ar_revid ON /*_*/archive (ar_rev_id);


--
-- Track page-to-page hyperlinks within the wiki.
--
CREATE TABLE /*_*/pagelinks (
   pl_from INT NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
   pl_namespace INT NOT NULL DEFAULT 0,
   pl_title NVARCHAR(255) NOT NULL DEFAULT '',
);
CREATE UNIQUE INDEX /*i*/pl_from ON /*_*/pagelinks (pl_from,pl_namespace,pl_title);
CREATE UNIQUE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from);


--
-- Track template inclusions.
--
CREATE TABLE /*_*/templatelinks (
  tl_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
  tl_namespace int NOT NULL default 0,
  tl_title nvarchar(255) NOT NULL default ''
);

CREATE UNIQUE INDEX /*i*/tl_from ON /*_*/templatelinks (tl_from,tl_namespace,tl_title);
CREATE UNIQUE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from);


--
-- Track links to images *used inline*
-- We don't distinguish live from broken links here, so
-- they do not need to be changed on upload/removal.
--
CREATE TABLE /*_*/imagelinks (
  -- Key to page_id of the page containing the image / media link.
  il_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,

  -- Filename of target image.
  -- This is also the page_title of the file's description page;
  -- all such pages are in namespace 6 (NS_FILE).
  il_to nvarchar(255) NOT NULL default ''
);

CREATE UNIQUE INDEX /*i*/il_from ON /*_*/imagelinks (il_from,il_to);
CREATE UNIQUE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from);

--
-- Track category inclusions *used inline*
-- This tracks a single level of category membership
--
CREATE TABLE /*_*/categorylinks (
  -- Key to page_id of the page defined as a category member.
  cl_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,

  -- Name of the category.
  -- This is also the page_title of the category's description page;
  -- all such pages are in namespace 14 (NS_CATEGORY).
  cl_to nvarchar(255) NOT NULL default '',

  -- A binary string obtained by applying a sortkey generation algorithm
  -- (Collation::getSortKey()) to page_title, or cl_sortkey_prefix . "\n"
  -- . page_title if cl_sortkey_prefix is nonempty.
  cl_sortkey varbinary(230) NOT NULL default 0x,

  -- A prefix for the raw sortkey manually specified by the user, either via
  -- [[Category:Foo|prefix]] or {{defaultsort:prefix}}.  If nonempty, it's
  -- concatenated with a line break followed by the page title before the sortkey
  -- conversion algorithm is run.  We store this so that we can update
  -- collations without reparsing all pages.
  -- Note: If you change the length of this field, you also need to change
  -- code in LinksUpdate.php. See bug 25254.
  cl_sortkey_prefix varbinary(255) NOT NULL default 0x,

  -- This isn't really used at present. Provided for an optional
  -- sorting method by approximate addition time.
  cl_timestamp varchar(14) NOT NULL,

  -- Stores $wgCategoryCollation at the time cl_sortkey was generated.  This
  -- can be used to install new collation versions, tracking which rows are not
  -- yet updated.  '' means no collation, this is a legacy row that needs to be
  -- updated by updateCollation.php.  In the future, it might be possible to
  -- specify different collations per category.
  cl_collation nvarchar(32) NOT NULL default '',

  -- Stores whether cl_from is a category, file, or other page, so we can
  -- paginate the three categories separately.  This never has to be updated
  -- after the page is created, since none of these page types can be moved to
  -- any other.
  cl_type varchar(10) NOT NULL default 'page',
  -- SQL server doesn't have enums, so we approximate with this
  CONSTRAINT cl_type_ckc CHECK (cl_type IN('page', 'subcat', 'file'))
);

CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to);

-- We always sort within a given category, and within a given type.  FIXME:
-- Formerly this index didn't cover cl_type (since that didn't exist), so old
-- callers won't be using an index: fix this?
CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_type,cl_sortkey,cl_from);

-- Used by the API (and some extensions)
CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);

-- FIXME: Not used, delete this
CREATE INDEX /*i*/cl_collation ON /*_*/categorylinks (cl_collation);

--
-- Track all existing categories.  Something is a category if 1) it has an en-
-- try somewhere in categorylinks, or 2) it once did.  Categories might not
-- have corresponding pages, so they need to be tracked separately.
--
CREATE TABLE /*_*/category (
  -- Primary key
  cat_id int NOT NULL PRIMARY KEY IDENTITY,

  -- Name of the category, in the same form as page_title (with underscores).
  -- If there is a category page corresponding to this category, by definition,
  -- it has this name (in the Category namespace).
  cat_title nvarchar(255) NOT NULL,

  -- The numbers of member pages (including categories and media), subcatego-
  -- ries, and Image: namespace members, respectively.  These are signed to
  -- make underflow more obvious.  We make the first number include the second
  -- two for better sorting: subtracting for display is easy, adding for order-
  -- ing is not.
  cat_pages int NOT NULL default 0,
  cat_subcats int NOT NULL default 0,
  cat_files int NOT NULL default 0
);

CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);

-- For Special:Mostlinkedcategories
CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);


--
-- Track links to external URLs
--
CREATE TABLE /*_*/externallinks (
  -- Primary key
  el_id int NOT NULL PRIMARY KEY IDENTITY,

  -- page_id of the referring page
  el_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,

  -- The URL
  el_to nvarchar(max) NOT NULL,

  -- In the case of HTTP URLs, this is the URL with any username or password
  -- removed, and with the labels in the hostname reversed and converted to
  -- lower case. An extra dot is added to allow for matching of either
  -- example.com or *.example.com in a single scan.
  -- Example:
  --      http://user:password@sub.example.com/page.html
  --   becomes
  --      http://com.example.sub./page.html
  -- which allows for fast searching for all pages under example.com with the
  -- clause:
  --      WHERE el_index LIKE 'http://com.example.%'
  el_index nvarchar(450) NOT NULL
);

CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from);
CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index);

--
-- Track interlanguage links
--
CREATE TABLE /*_*/langlinks (
  -- page_id of the referring page
  ll_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,

  -- Language code of the target
  ll_lang nvarchar(20) NOT NULL default '',

  -- Title of the target, including namespace
  ll_title nvarchar(255) NOT NULL default ''
);

CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang);
CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);


--
-- Track inline interwiki links
--
CREATE TABLE /*_*/iwlinks (
  -- page_id of the referring page
  iwl_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,

  -- Interwiki prefix code of the target
  iwl_prefix nvarchar(20) NOT NULL default '',

  -- Title of the target, including namespace
  iwl_title nvarchar(255) NOT NULL default ''
);

CREATE UNIQUE INDEX /*i*/iwl_from ON /*_*/iwlinks (iwl_from, iwl_prefix, iwl_title);
CREATE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from);
CREATE INDEX /*i*/iwl_prefix_from_title ON /*_*/iwlinks (iwl_prefix, iwl_from, iwl_title);


--
-- Contains a single row with some aggregate info
-- on the state of the site.
--
CREATE TABLE /*_*/site_stats (
  -- The single row should contain 1 here.
  ss_row_id int NOT NULL,

  -- Total number of edits performed.
  ss_total_edits bigint default 0,

  -- An approximate count of pages matching the following criteria:
  -- * in namespace 0
  -- * not a redirect
  -- * contains the text '[['
  -- See Article::isCountable() in includes/Article.php
  ss_good_articles bigint default 0,

  -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
  ss_total_pages bigint default '-1',

  -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
  ss_users bigint default '-1',

  -- Number of users that still edit
  ss_active_users bigint default '-1',

  -- Number of images, equivalent to SELECT COUNT(*) FROM image
  ss_images int default 0
);

-- Pointless index to assuage developer superstitions
CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id);


--
-- The internet is full of jerks, alas. Sometimes it's handy
-- to block a vandal or troll account.
--
CREATE TABLE /*_*/ipblocks (
  -- Primary key, introduced for privacy.
  ipb_id int NOT NULL PRIMARY KEY IDENTITY,

  -- Blocked IP address in dotted-quad form or user name.
  ipb_address nvarchar(255) NOT NULL,

  -- Blocked user ID or 0 for IP blocks.
  ipb_user int REFERENCES /*_*/mwuser(user_id),

  -- User ID who made the block.
  ipb_by int REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,

  -- User name of blocker
  ipb_by_text nvarchar(255) NOT NULL default '',

  -- Text comment made by blocker.
  ipb_reason nvarchar(255) NOT NULL,

  -- Creation (or refresh) date in standard YMDHMS form.
  -- IP blocks expire automatically.
  ipb_timestamp varchar(14) NOT NULL default '',

  -- Indicates that the IP address was banned because a banned
  -- user accessed a page through it. If this is 1, ipb_address
  -- will be hidden, and the block identified by block ID number.
  ipb_auto bit NOT NULL default 0,

  -- If set to 1, block applies only to logged-out users
  ipb_anon_only bit NOT NULL default 0,

  -- Block prevents account creation from matching IP addresses
  ipb_create_account bit NOT NULL default 1,

  -- Block triggers autoblocks
  ipb_enable_autoblock bit NOT NULL default 1,

  -- Time at which the block will expire.
  -- May be "infinity"
  ipb_expiry varchar(14) NOT NULL,

  -- Start and end of an address range, in hexadecimal
  -- Size chosen to allow IPv6
  -- FIXME: these fields were originally blank for single-IP blocks,
  -- but now they are populated. No migration was ever done. They
  -- should be fixed to be blank again for such blocks (bug 49504).
  ipb_range_start varchar(255) NOT NULL,
  ipb_range_end varchar(255) NOT NULL,

  -- Flag for entries hidden from users and Sysops
  ipb_deleted bit NOT NULL default 0,

  -- Block prevents user from accessing Special:Emailuser
  ipb_block_email bit NOT NULL default 0,

  -- Block allows user to edit their own talk page
  ipb_allow_usertalk bit NOT NULL default 0,

  -- ID of the block that caused this block to exist
  -- Autoblocks set this to the original block
  -- so that the original block being deleted also
  -- deletes the autoblocks
  ipb_parent_block_id int default NULL REFERENCES /*_*/ipblocks(ipb_id)

);

-- Unique index to support "user already blocked" messages
-- Any new options which prevent collisions should be included
CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address, ipb_user, ipb_auto, ipb_anon_only);

CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start, ipb_range_end);
CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
CREATE INDEX /*i*/ipb_parent_block_id ON /*_*/ipblocks (ipb_parent_block_id);


--
-- Uploaded images and other files.
--
CREATE TABLE /*_*/image (
  -- Filename.
  -- This is also the title of the associated description page,
  -- which will be in namespace 6 (NS_FILE).
  img_name varbinary(255) NOT NULL default 0x PRIMARY KEY,

  -- File size in bytes.
  img_size int NOT NULL default 0,

  -- For images, size in pixels.
  img_width int NOT NULL default 0,
  img_height int NOT NULL default 0,

  -- Extracted Exif metadata stored as a serialized PHP array.
  img_metadata varbinary(max) NOT NULL,

  -- For images, bits per pixel if known.
  img_bits int NOT NULL default 0,

  -- Media type as defined by the MEDIATYPE_xxx constants
  img_media_type varchar(16) default null,

  -- major part of a MIME media type as defined by IANA
  -- see http://www.iana.org/assignments/media-types/
  img_major_mime varchar(16) not null default 'unknown',

  -- minor part of a MIME media type as defined by IANA
  -- the minor parts are not required to adher to any standard
  -- but should be consistent throughout the database
  -- see http://www.iana.org/assignments/media-types/
  img_minor_mime nvarchar(100) NOT NULL default 'unknown',

  -- Description field as entered by the uploader.
  -- This is displayed in image upload history and logs.
  img_description nvarchar(255) NOT NULL,

  -- user_id and user_name of uploader.
  img_user int REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
  img_user_text nvarchar(255) NOT NULL,

  -- Time of the upload.
  img_timestamp nvarchar(14) NOT NULL default '',

  -- SHA-1 content hash in base-36
  img_sha1 nvarchar(32) NOT NULL default '',

  CONSTRAINT img_major_mime_ckc check (img_major_mime IN('unknown', 'application', 'audio', 'image', 'text', 'video', 'message', 'model', 'multipart', 'chemical')),
  CONSTRAINT img_media_type_ckc check (img_media_type in('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
);

CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
-- Used by Special:ListFiles for sort-by-size
CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
-- Used by Special:Newimages and Special:ListFiles
CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
-- Used in API and duplicate search
CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1);
-- Used to get media of one type
CREATE INDEX /*i*/img_media_mime ON /*_*/image (img_media_type,img_major_mime,img_minor_mime);


--
-- Previous revisions of uploaded files.
-- Awkwardly, image rows have to be moved into
-- this table at re-upload time.
--
CREATE TABLE /*_*/oldimage (
  -- Base filename: key to image.img_name
  oi_name varbinary(255) NOT NULL default 0x REFERENCES /*_*/image(img_name) ON DELETE CASCADE ON UPDATE CASCADE,

  -- Filename of the archived file.
  -- This is generally a timestamp and '!' prepended to the base name.
  oi_archive_name varbinary(255) NOT NULL default 0x,

  -- Other fields as in image...
  oi_size int NOT NULL default 0,
  oi_width int NOT NULL default 0,
  oi_height int NOT NULL default 0,
  oi_bits int NOT NULL default 0,
  oi_description nvarchar(255) NOT NULL,
  oi_user int REFERENCES /*_*/mwuser(user_id),
  oi_user_text nvarchar(255) NOT NULL,
  oi_timestamp varchar(14) NOT NULL default '',

  oi_metadata nvarchar(max) NOT NULL,
  oi_media_type varchar(16) default null,
  oi_major_mime varchar(16) not null default 'unknown',
  oi_minor_mime nvarchar(100) NOT NULL default 'unknown',
  oi_deleted tinyint NOT NULL default 0,
  oi_sha1 nvarchar(32) NOT NULL default '',

  CONSTRAINT oi_major_mime_ckc check (oi_major_mime IN('unknown', 'application', 'audio', 'image', 'text', 'video', 'message', 'model', 'multipart', 'chemical')),
  CONSTRAINT oi_media_type_ckc check (oi_media_type IN('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
);

CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
-- oi_archive_name truncated to 14 to avoid key length overflow
CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name);
CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1);


--
-- Record of deleted file data
--
CREATE TABLE /*_*/filearchive (
  -- Unique row id
  fa_id int NOT NULL PRIMARY KEY IDENTITY,

  -- Original base filename; key to image.img_name, page.page_title, etc
  fa_name nvarchar(255) NOT NULL default '',

  -- Filename of archived file, if an old revision
  fa_archive_name nvarchar(255) default '',

  -- Which storage bin (directory tree or object store) the file data
  -- is stored in. Should be 'deleted' for files that have been deleted;
  -- any other bin is not yet in use.
  fa_storage_group nvarchar(16),

  -- SHA-1 of the file contents plus extension, used as a key for storage.
  -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
  --
  -- If NULL, the file was missing at deletion time or has been purged
  -- from the archival storage.
  fa_storage_key nvarchar(64) default '',

  -- Deletion information, if this file is deleted.
  fa_deleted_user int,
  fa_deleted_timestamp varchar(14) default '',
  fa_deleted_reason nvarchar(max),

  -- Duped fields from image
  fa_size int default 0,
  fa_width int default 0,
  fa_height int default 0,
  fa_metadata nvarchar(max),
  fa_bits int default 0,
  fa_media_type varchar(16) default null,
  fa_major_mime varchar(16) not null default 'unknown',
  fa_minor_mime nvarchar(100) default 'unknown',
  fa_description nvarchar(255),
  fa_user int default 0 REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
  fa_user_text nvarchar(255),
  fa_timestamp varchar(14) default '',

  -- Visibility of deleted revisions, bitfield
  fa_deleted tinyint NOT NULL default 0,

  -- sha1 hash of file content
  fa_sha1 nvarchar(32) NOT NULL default '',

  CONSTRAINT fa_major_mime_ckc check (fa_major_mime in('unknown', 'application', 'audio', 'image', 'text', 'video', 'message', 'model', 'multipart', 'chemical')),
  CONSTRAINT fa_media_type_ckc check (fa_media_type in('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
);

-- pick out by image name
CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
-- pick out dupe files
CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
-- sort by deletion time
CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
-- sort by uploader
CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
-- find file by sha1, 10 bytes will be enough for hashes to be indexed
CREATE INDEX /*i*/fa_sha1 ON /*_*/filearchive (fa_sha1);


--
-- Store information about newly uploaded files before they're
-- moved into the actual filestore
--
CREATE TABLE /*_*/uploadstash (
  us_id int NOT NULL PRIMARY KEY IDENTITY,

  -- the user who uploaded the file.
  us_user int REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,

  -- file key. this is how applications actually search for the file.
  -- this might go away, or become the primary key.
  us_key nvarchar(255) NOT NULL,

  -- the original path
  us_orig_path nvarchar(255) NOT NULL,

  -- the temporary path at which the file is actually stored
  us_path nvarchar(255) NOT NULL,

  -- which type of upload the file came from (sometimes)
  us_source_type nvarchar(50),

  -- the date/time on which the file was added
  us_timestamp varchar(14) NOT NULL,

  us_status nvarchar(50) NOT NULL,

  -- chunk counter starts at 0, current offset is stored in us_size
  us_chunk_inx int NULL,

  -- Serialized file properties from FSFile::getProps()
  us_props nvarchar(max),

  -- file size in bytes
  us_size int NOT NULL,
  -- this hash comes from FSFile::getSha1Base36(), and is 31 characters
  us_sha1 nvarchar(31) NOT NULL,
  us_mime nvarchar(255),
  -- Media type as defined by the MEDIATYPE_xxx constants, should duplicate definition in the image table
  us_media_type varchar(16) default null,
  -- image-specific properties
  us_image_width int,
  us_image_height int,
  us_image_bits smallint,

  CONSTRAINT us_media_type_ckc check (us_media_type in('UNKNOWN', 'BITMAP', 'DRAWING', 'AUDIO', 'VIDEO', 'MULTIMEDIA', 'OFFICE', 'TEXT', 'EXECUTABLE', 'ARCHIVE'))
);

-- sometimes there's a delete for all of a user's stuff.
CREATE INDEX /*i*/us_user ON /*_*/uploadstash (us_user);
-- pick out files by key, enforce key uniqueness
CREATE UNIQUE INDEX /*i*/us_key ON /*_*/uploadstash (us_key);
-- the abandoned upload cleanup script needs this
CREATE INDEX /*i*/us_timestamp ON /*_*/uploadstash (us_timestamp);


--
-- Primarily a summary table for Special:Recentchanges,
-- this table contains some additional info on edits from
-- the last few days, see Article::editUpdates()
--
CREATE TABLE /*_*/recentchanges (
  rc_id int NOT NULL PRIMARY KEY IDENTITY,
  rc_timestamp varchar(14) not null default '',

  -- This is no longer used
  -- Field kept in database for downgrades
  -- @todo: add drop patch with 1.24
  rc_cur_time varchar(14) NOT NULL default '',

  -- As in revision
  rc_user int NOT NULL default 0 REFERENCES /*_*/mwuser(user_id),
  rc_user_text nvarchar(255) NOT NULL,

  -- When pages are renamed, their RC entries do _not_ change.
  rc_namespace int NOT NULL default 0,
  rc_title nvarchar(255) NOT NULL default '',

  -- as in revision...
  rc_comment nvarchar(255) NOT NULL default '',
  rc_minor bit NOT NULL default 0,

  -- Edits by user accounts with the 'bot' rights key are
  -- marked with a 1 here, and will be hidden from the
  -- default view.
  rc_bot bit NOT NULL default 0,

  -- Set if this change corresponds to a page creation
  rc_new bit NOT NULL default 0,

  -- Key to page_id (was cur_id prior to 1.5).
  -- This will keep links working after moves while
  -- retaining the at-the-time name in the changes list.
  rc_cur_id int REFERENCES /*_*/page(page_id),

  -- rev_id of the given revision
  rc_this_oldid int REFERENCES /*_*/revision(rev_id),

  -- rev_id of the prior revision, for generating diff links.
  rc_last_oldid int REFERENCES /*_*/revision(rev_id),

  -- The type of change entry (RC_EDIT,RC_NEW,RC_LOG,RC_EXTERNAL)
  rc_type tinyint NOT NULL default 0,

  -- The source of the change entry (replaces rc_type)
  -- default of '' is temporary, needed for initial migration
  rc_source nvarchar(16) not null default '',

  -- If the Recent Changes Patrol option is enabled,
  -- users may mark edits as having been reviewed to
  -- remove a warning flag on the RC list.
  -- A value of 1 indicates the page has been reviewed.
  rc_patrolled bit NOT NULL default 0,

  -- Recorded IP address the edit was made from, if the
  -- $wgPutIPinRC option is enabled.
  rc_ip nvarchar(40) NOT NULL default '',

  -- Text length in characters before
  -- and after the edit
  rc_old_len int,
  rc_new_len int,

  -- Visibility of recent changes items, bitfield
  rc_deleted tinyint NOT NULL default 0,

  -- Value corresponding to log_id, specific log entries
  rc_logid int, -- FK added later
  -- Store log type info here, or null
  rc_log_type nvarchar(255) NULL default NULL,
  -- Store log action or null
  rc_log_action nvarchar(255) NULL default NULL,
  -- Log params
  rc_params nvarchar(max) NULL
);

CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);


CREATE TABLE /*_*/watchlist (
  -- Key to user.user_id
  wl_user int NOT NULL REFERENCES /*_*/mwuser(user_id) ON DELETE CASCADE,

  -- Key to page_namespace/page_title
  -- Note that users may watch pages which do not exist yet,
  -- or existed in the past but have been deleted.
  wl_namespace int NOT NULL default 0,
  wl_title nvarchar(255) NOT NULL default '',

  -- Timestamp used to send notification e-mails and show "updated since last visit" markers on
  -- history and recent changes / watchlist. Set to NULL when the user visits the latest revision
  -- of the page, which means that they should be sent an e-mail on the next change.
  wl_notificationtimestamp varchar(14)

);

CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);


--
-- Our search index for the builtin MediaWiki search
--
CREATE TABLE /*_*/searchindex (
  -- Key to page_id
  si_page int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,

  -- Munged version of title
  si_title nvarchar(255) NOT NULL default '',

  -- Munged version of body text
  si_text nvarchar(max) NOT NULL
);

CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
-- Fulltext index is defined in MssqlInstaller.php

--
-- Recognized interwiki link prefixes
--
CREATE TABLE /*_*/interwiki (
  -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
  iw_prefix nvarchar(32) NOT NULL,

  -- The URL of the wiki, with "$1" as a placeholder for an article name.
  -- Any spaces in the name will be transformed to underscores before
  -- insertion.
  iw_url nvarchar(max) NOT NULL,

  -- The URL of the file api.php
  iw_api nvarchar(max) NOT NULL,

  -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' ))
  iw_wikiid nvarchar(64) NOT NULL,

  -- A boolean value indicating whether the wiki is in this project
  -- (used, for example, to detect redirect loops)
  iw_local bit NOT NULL,

  -- Boolean value indicating whether interwiki transclusions are allowed.
  iw_trans bit NOT NULL default 0
);

CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);


--
-- Used for caching expensive grouped queries
--
CREATE TABLE /*_*/querycache (
  -- A key name, generally the base name of of the special page.
  qc_type nvarchar(32) NOT NULL,

  -- Some sort of stored value. Sizes, counts...
  qc_value int NOT NULL default 0,

  -- Target namespace+title
  qc_namespace int NOT NULL default 0,
  qc_title nvarchar(255) NOT NULL default ''
);

CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);


--
-- For a few generic cache operations if not using Memcached
--
CREATE TABLE /*_*/objectcache (
  keyname nvarchar(255) NOT NULL default '' PRIMARY KEY,
  value varbinary(max),
  exptime varchar(14)
);
CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);


--
-- Cache of interwiki transclusion
--
CREATE TABLE /*_*/transcache (
  tc_url nvarchar(255) NOT NULL,
  tc_contents nvarchar(max),
  tc_time varchar(14) NOT NULL
);

CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url);


CREATE TABLE /*_*/logging (
  -- Log ID, for referring to this specific log entry, probably for deletion and such.
  log_id int NOT NULL PRIMARY KEY IDENTITY(0,1),

  -- Symbolic keys for the general log type and the action type
  -- within the log. The output format will be controlled by the
  -- action field, but only the type controls categorization.
  log_type nvarchar(32) NOT NULL default '',
  log_action nvarchar(32) NOT NULL default '',

  -- Timestamp. Duh.
  log_timestamp varchar(14) NOT NULL default '',

  -- The user who performed this action; key to user_id
  log_user int REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,

  -- Name of the user who performed this action
  log_user_text nvarchar(255) NOT NULL default '',

  -- Key to the page affected. Where a user is the target,
  -- this will point to the user page.
  log_namespace int NOT NULL default 0,
  log_title nvarchar(255) NOT NULL default '',
  log_page int NULL REFERENCES /*_*/page(page_id) ON DELETE SET NULL,

  -- Freeform text. Interpreted as edit history comments.
  log_comment nvarchar(255) NOT NULL default '',

  -- miscellaneous parameters:
  -- LF separated list (old system) or serialized PHP array (new system)
  log_params nvarchar(max) NOT NULL,

  -- rev_deleted for logs
  log_deleted tinyint NOT NULL default 0
);

CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp);
CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp);
CREATE INDEX /*i*/type_action ON /*_*/logging (log_type, log_action, log_timestamp);
CREATE INDEX /*i*/log_user_text_type_time ON /*_*/logging (log_user_text, log_type, log_timestamp);
CREATE INDEX /*i*/log_user_text_time ON /*_*/logging (log_user_text, log_timestamp);

INSERT INTO /*_*/logging (log_user,log_page,log_params) VALUES(0,0,'');

ALTER TABLE /*_*/recentchanges ADD CONSTRAINT FK_rc_logid_log_id FOREIGN KEY (rc_logid) REFERENCES /*_*/logging(log_id) ON DELETE CASCADE;

CREATE TABLE /*_*/log_search (
  -- The type of ID (rev ID, log ID, rev timestamp, username)
  ls_field nvarchar(32) NOT NULL,
  -- The value of the ID
  ls_value nvarchar(255) NOT NULL,
  -- Key to log_id
  ls_log_id int REFERENCES /*_*/logging(log_id) ON DELETE CASCADE
);
CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id);
CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);


-- Jobs performed by parallel apache threads or a command-line daemon
CREATE TABLE /*_*/job (
  job_id int NOT NULL PRIMARY KEY IDENTITY,

  -- Command name
  -- Limited to 60 to prevent key length overflow
  job_cmd nvarchar(60) NOT NULL default '',

  -- Namespace and title to act on
  -- Should be 0 and '' if the command does not operate on a title
  job_namespace int NOT NULL,
  job_title nvarchar(255) NOT NULL,

  -- Timestamp of when the job was inserted
  -- NULL for jobs added before addition of the timestamp
  job_timestamp nvarchar(14) NULL default NULL,

  -- Any other parameters to the command
  -- Stored as a PHP serialized array, or an empty string if there are no parameters
  job_params nvarchar(max) NOT NULL,

  -- Random, non-unique, number used for job acquisition (for lock concurrency)
  job_random int NOT NULL default 0,

  -- The number of times this job has been locked
  job_attempts int NOT NULL default 0,

  -- Field that conveys process locks on rows via process UUIDs
  job_token nvarchar(32) NOT NULL default '',

  -- Timestamp when the job was locked
  job_token_timestamp varchar(14) NULL default NULL,

  -- Base 36 SHA1 of the job parameters relevant to detecting duplicates
  job_sha1 nvarchar(32) NOT NULL default ''
);

CREATE INDEX /*i*/job_sha1 ON /*_*/job (job_sha1);
CREATE INDEX /*i*/job_cmd_token ON /*_*/job (job_cmd,job_token,job_random);
CREATE INDEX /*i*/job_cmd_token_id ON /*_*/job (job_cmd,job_token,job_id);
CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title);
CREATE INDEX /*i*/job_timestamp ON /*_*/job (job_timestamp);


-- Details of updates to cached special pages
CREATE TABLE /*_*/querycache_info (
  -- Special page name
  -- Corresponds to a qc_type value
  qci_type nvarchar(32) NOT NULL default '',

  -- Timestamp of last update
  qci_timestamp varchar(14) NOT NULL default ''
);

CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type);


-- For each redirect, this table contains exactly one row defining its target
CREATE TABLE /*_*/redirect (
  -- Key to the page_id of the redirect page
  rd_from int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,

  -- Key to page_namespace/page_title of the target page.
  -- The target page may or may not exist, and due to renames
  -- and deletions may refer to different page records as time
  -- goes by.
  rd_namespace int NOT NULL default 0,
  rd_title nvarchar(255) NOT NULL default '',
  rd_interwiki nvarchar(32) default NULL,
  rd_fragment nvarchar(255) default NULL
);

CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);


-- Used for caching expensive grouped queries that need two links (for example double-redirects)
CREATE TABLE /*_*/querycachetwo (
  -- A key name, generally the base name of of the special page.
  qcc_type nvarchar(32) NOT NULL,

  -- Some sort of stored value. Sizes, counts...
  qcc_value int NOT NULL default 0,

  -- Target namespace+title
  qcc_namespace int NOT NULL default 0,
  qcc_title nvarchar(255) NOT NULL default '',

  -- Target namespace+title2
  qcc_namespacetwo int NOT NULL default 0,
  qcc_titletwo nvarchar(255) NOT NULL default ''
);

CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);


-- Used for storing page restrictions (i.e. protection levels)
CREATE TABLE /*_*/page_restrictions (
  -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
  pr_id int NOT NULL PRIMARY KEY IDENTITY,
  -- Page to apply restrictions to (Foreign Key to page).
  pr_page int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
  -- The protection type (edit, move, etc)
  pr_type nvarchar(60) NOT NULL,
  -- The protection level (Sysop, autoconfirmed, etc)
  pr_level nvarchar(60) NOT NULL,
  -- Whether or not to cascade the protection down to pages transcluded.
  pr_cascade bit NOT NULL,
  -- Field for future support of per-user restriction.
  pr_user int NULL,
  -- Field for time-limited protection.
  pr_expiry varchar(14) NULL
);

CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);


-- Protected titles - nonexistent pages that have been protected
CREATE TABLE /*_*/protected_titles (
  pt_namespace int NOT NULL,
  pt_title nvarchar(255) NOT NULL,
  pt_user int REFERENCES /*_*/mwuser(user_id) ON DELETE SET NULL,
  pt_reason nvarchar(255),
  pt_timestamp varchar(14) NOT NULL,
  pt_expiry varchar(14) NOT NULL,
  pt_create_perm nvarchar(60) NOT NULL
);

CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);


-- Name/value pairs indexed by page_id
CREATE TABLE /*_*/page_props (
  pp_page int NOT NULL REFERENCES /*_*/page(page_id) ON DELETE CASCADE,
  pp_propname nvarchar(60) NOT NULL,
  pp_value nvarchar(max) NOT NULL
);

CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
CREATE UNIQUE INDEX /*i*/pp_propname_page ON /*_*/page_props (pp_propname,pp_page);


-- A table to log updates, one text key row per update.
CREATE TABLE /*_*/updatelog (
  ul_key nvarchar(255) NOT NULL PRIMARY KEY,
  ul_value nvarchar(max)
);


-- A table to track tags for revisions, logs and recent changes.
CREATE TABLE /*_*/change_tag (
  -- RCID for the change
  ct_rc_id int NULL REFERENCES /*_*/recentchanges(rc_id),
  -- LOGID for the change
  ct_log_id int NULL REFERENCES /*_*/logging(log_id),
  -- REVID for the change
  ct_rev_id int NULL REFERENCES /*_*/revision(rev_id),
  -- Tag applied
  ct_tag nvarchar(255) NOT NULL,
  -- Parameters for the tag, presently unused
  ct_params nvarchar(max) NULL
);

CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
-- Covering index, so we can pull all the info only out of the index.
CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);


-- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
-- that only works on MySQL 4.1+
CREATE TABLE /*_*/tag_summary (
  -- RCID for the change
  ts_rc_id int NULL REFERENCES /*_*/recentchanges(rc_id),
  -- LOGID for the change
  ts_log_id int NULL REFERENCES /*_*/logging(log_id),
  -- REVID for the change
  ts_rev_id int NULL REFERENCES /*_*/revision(rev_id),
  -- Comma-separated list of tags
  ts_tags nvarchar(max) NOT NULL
);

CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);


CREATE TABLE /*_*/valid_tag (
  vt_tag nvarchar(255) NOT NULL PRIMARY KEY
);

-- Table for storing localisation data
CREATE TABLE /*_*/l10n_cache (
  -- Language code
  lc_lang nvarchar(32) NOT NULL,
  -- Cache key
  lc_key nvarchar(255) NOT NULL,
  -- Value
  lc_value varbinary(max) NOT NULL
);
CREATE INDEX /*i*/lc_lang_key ON /*_*/l10n_cache (lc_lang, lc_key);

-- Table for caching JSON message texts for the resource loader
CREATE TABLE /*_*/msg_resource (
  -- Resource name
  mr_resource nvarchar(255) NOT NULL,
  -- Language code
  mr_lang nvarchar(32) NOT NULL,
  -- JSON blob
  mr_blob varbinary(max) NOT NULL,
  -- Timestamp of last update
  mr_timestamp varchar(14) NOT NULL
);
CREATE UNIQUE INDEX /*i*/mr_resource_lang ON /*_*/msg_resource (mr_resource, mr_lang);

-- Table for administering which message is contained in which resource
CREATE TABLE /*_*/msg_resource_links (
  mrl_resource varbinary(255) NOT NULL,
  -- Message key
  mrl_message varbinary(255) NOT NULL
);
CREATE UNIQUE INDEX /*i*/mrl_message_resource ON /*_*/msg_resource_links (mrl_message, mrl_resource);

-- Table caching which local files a module depends on that aren't
-- registered directly, used for fast retrieval of file dependency.
-- Currently only used for tracking images that CSS depends on
CREATE TABLE /*_*/module_deps (
  -- Module name
  md_module nvarchar(255) NOT NULL,
  -- Skin name
  md_skin nvarchar(32) NOT NULL,
  -- JSON nvarchar(max) with file dependencies
  md_deps nvarchar(max) NOT NULL
);
CREATE UNIQUE INDEX /*i*/md_module_skin ON /*_*/module_deps (md_module, md_skin);

-- Holds all the sites known to the wiki.
CREATE TABLE /*_*/sites (
  -- Numeric id of the site
  site_id                    int        NOT NULL PRIMARY KEY IDENTITY,

  -- Global identifier for the site, ie 'enwiktionary'
  site_global_key            nvarchar(32)       NOT NULL,

  -- Type of the site, ie 'mediawiki'
  site_type                  nvarchar(32)       NOT NULL,

  -- Group of the site, ie 'wikipedia'
  site_group                 nvarchar(32)       NOT NULL,

  -- Source of the site data, ie 'local', 'wikidata', 'my-magical-repo'
  site_source                nvarchar(32)       NOT NULL,

  -- Language code of the sites primary language.
  site_language              nvarchar(32)       NOT NULL,

  -- Protocol of the site, ie 'http://', 'irc://', '//'
  -- This field is an index for lookups and is build from type specific data in site_data.
  site_protocol              nvarchar(32)       NOT NULL,

  -- Domain of the site in reverse order, ie 'org.mediawiki.www.'
  -- This field is an index for lookups and is build from type specific data in site_data.
  site_domain                NVARCHAR(255)        NOT NULL,

  -- Type dependent site data.
  site_data                  nvarchar(max)                NOT NULL,

  -- If site.tld/path/key:pageTitle should forward users to  the page on
  -- the actual site, where "key" is the local identifier.
  site_forward              bit                NOT NULL,

  -- Type dependent site config.
  -- For instance if template transclusion should be allowed if it's a MediaWiki.
  site_config               nvarchar(max)                NOT NULL
);

CREATE UNIQUE INDEX /*i*/sites_global_key ON /*_*/sites (site_global_key);
CREATE INDEX /*i*/sites_type ON /*_*/sites (site_type);
CREATE INDEX /*i*/sites_group ON /*_*/sites (site_group);
CREATE INDEX /*i*/sites_source ON /*_*/sites (site_source);
CREATE INDEX /*i*/sites_language ON /*_*/sites (site_language);
CREATE INDEX /*i*/sites_protocol ON /*_*/sites (site_protocol);
CREATE INDEX /*i*/sites_domain ON /*_*/sites (site_domain);
CREATE INDEX /*i*/sites_forward ON /*_*/sites (site_forward);

-- Links local site identifiers to their corresponding site.
CREATE TABLE /*_*/site_identifiers (
  -- Key on site.site_id
  si_site                    int        NOT NULL REFERENCES /*_*/sites(site_id) ON DELETE CASCADE,

  -- local key type, ie 'interwiki' or 'langlink'
  si_type                    nvarchar(32)       NOT NULL,

  -- local key value, ie 'en' or 'wiktionary'
  si_key                     nvarchar(32)       NOT NULL
);

CREATE UNIQUE INDEX /*i*/site_ids_type ON /*_*/site_identifiers (si_type, si_key);
CREATE INDEX /*i*/site_ids_site ON /*_*/site_identifiers (si_site);
CREATE INDEX /*i*/site_ids_key ON /*_*/site_identifiers (si_key);