-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathInstallDataChanges.sql
596 lines (531 loc) · 35.4 KB
/
InstallDataChanges.sql
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
/********************************************************************************
***
*** This query is designed to create an update script for all tables loaded
*** by the [Framework.].LoadInstallData stored procedure.
***
*** The script relies on the fact that each table will have a set of columns
*** that must be unique, and insert any rows that are missing using these
*** columns, and update any rows where other columns have changed.
***
*** [Framework.].[Parameter] (ParameterID), (Value)
*** [Framework.].[RestPath] (ApplicationName), Resolver
*** [Framework.].[Job] -- Skipping this for now,
*** [Framework.].[JobGroup]
*** [Ontology.].[ClassGroup]
*** [Ontology.].[ClassGroupClass]
*** [Ontology.].[ClassProperty]
*** [Ontology.].[DataMap]
*** [Ontology.].[Namespace]
*** [Ontology.].[PropertyGroup]
*** [Ontology.].[PropertyGroupProperty]
*** [Ontology.Presentation].[XML]
*** [RDF.Security].[Group]
*** [Utility.NLP].[ParsePorterStemming]
*** [Utility.NLP].[StopWord]
*** [Utility.NLP].[Thesaurus.Source]
*** [User.Session].Bot
*** [Direct.].[Sites]
*** [Profile.Data].[Publication.Type]
*** [Profile.Data].[Publication.MyPub.Category]
*** [ORCID.].[REF_Permission]
*** [ORCID.].[REF_PersonStatusType]
*** [ORCID.].[REF_WorkExternalType]
*** [ORCID.].[REF_RecordStatus]
*** [ORCID.].[REF_Decision]
*** [ORCID.].[RecordLevelAuditType]
*** [ORCID.].[DefaultORCIDDecisionIDMapping]
*** [ORNG.].[Apps]
*** [ORNG.].[AppViews]
***
*** Tables that have not been automated
*** select * from [Framework.].[Job]
*** select * from [User.Session].Bot
***
********************************************************************************/
create table #ColumnsToSync
( SyncTable nvarchar(255),
IndexColumn nvarchar(255),
-- IndexColumnCompare nvarchar(255),
SyncColumn nvarchar(255),
IdentityColumn nvarchar(255)
-- SyncColumnCompare nvarchar(255)
)
--drop table #ColumnsToSync
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Framework.].[Parameter]', 'ParameterID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Framework.].[Parameter]', 'Value')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Framework.].[RestPath]', 'ApplicationName')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Framework.].[RestPath]', 'Resolver')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Framework.].[Job]', 'JobGroup')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Framework.].[Job]', 'Script')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Framework.].[Job]', 'IsActive')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Framework.].[Job]', 'Step')
Insert into #ColumnsToSync (SyncTable, IdentityColumn) values ('[Framework.].[Job]', 'JobID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Framework.].[JobGroup]', 'JobGroup')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Framework.].[JobGroup]', 'Name')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Framework.].[JobGroup]', 'Type')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Framework.].[JobGroup]', 'Description')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[ClassGroup]', 'ClassGroupURI')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassGroup]', 'SortOrder')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassGroup]', '_ClassGroupLabel')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassGroup]', 'IsVisible')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[ClassGroupClass]', 'ClassGroupURI')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[ClassGroupClass]', 'ClassURI')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassGroupClass]', 'SortOrder')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassGroupClass]', '_ClassLabel')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[ClassProperty]', 'Class')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[ClassProperty]', 'NetworkProperty')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[ClassProperty]', 'Property')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'IsDetail')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'Limit')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'IncludeDescription')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'IncludeNetwork')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'SearchWeight')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'CustomDisplay')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'CustomEdit')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'ViewSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'EditSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'EditPermissionsSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'EditExistingSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'EditAddNewSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'EditAddExistingSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'EditDeleteSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'MinCardinality')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'MaxCardinality')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'CustomDisplayModule')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', 'CustomEditModule')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', '_TagName')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', '_PropertyLabel')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[ClassProperty]', '_ObjectType')
Insert into #ColumnsToSync (SyncTable, IdentityColumn) values ('[Ontology.].[ClassProperty]', 'ClassPropertyID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[DataMap]', 'DataMapGroup')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[DataMap]', 'IsAutoFeed')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[DataMap]', 'Graph')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[DataMap]', 'Class')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[DataMap]', 'NetworkProperty')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[DataMap]', 'Property')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[DataMap]', 'MapTable')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'sInternalType')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'sInternalID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'cClass')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'cInternalType')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'cInternalID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oClass')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oInternalType')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oInternalID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oValue')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oDataType')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oLanguage')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oStartDate')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oStartDatePrecision')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oEndDate')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oEndDatePrecision')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'oObjectType')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'Weight')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'OrderBy')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'ViewSecurityGroup')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[DataMap]', 'EditSecurityGroup')
Insert into #ColumnsToSync (SyncTable, IdentityColumn) values ('[Ontology.].[DataMap]', 'DataMapID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[Namespace]', 'URI')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[Namespace]', 'Prefix')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[PropertyGroup]', 'PropertyGroupURI')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[PropertyGroup]', 'SortOrder')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[PropertyGroup]', '_PropertyGroupLabel')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[PropertyGroupProperty]', 'PropertyGroupURI')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.].[PropertyGroupProperty]', 'PropertyURI')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[PropertyGroupProperty]', 'SortOrder')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[PropertyGroupProperty]', 'CustomDisplayModule')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.].[PropertyGroupProperty]', 'CustomEditModule')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.Presentation].[XML]', 'Type')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.Presentation].[XML]', 'Subject')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.Presentation].[XML]', 'Predicate')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Ontology.Presentation].[XML]', 'Object')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Ontology.Presentation].[XML]', 'PresentationXML')
Insert into #ColumnsToSync (SyncTable, IdentityColumn) values ('[Ontology.Presentation].[XML]', 'PresentationID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[RDF.Security].[Group]', 'SecurityGroupID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[RDF.Security].[Group]', 'Label')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[RDF.Security].[Group]', 'HasSpecialViewAccess')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[RDF.Security].[Group]', 'HasSpecialEditAccess')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[RDF.Security].[Group]', 'Description')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Utility.NLP].[ParsePorterStemming]', 'Step')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Utility.NLP].[ParsePorterStemming]', 'Ordering')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Utility.NLP].[ParsePorterStemming]', 'phrase1')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Utility.NLP].[ParsePorterStemming]', 'phrase2')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Utility.NLP].[StopWord]', 'word')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Utility.NLP].[StopWord]', 'stem')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Utility.NLP].[StopWord]', 'scope')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Utility.NLP].[Thesaurus.Source]', 'SourceName')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Utility.NLP].[Thesaurus.Source]', 'Source')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[User.Session].[Bot]', 'UserAgent')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Direct.].[Sites]', 'SiteName')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Direct.].[Sites]', 'BootstrapURL')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Direct.].[Sites]', 'QueryURL')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Direct.].[Sites]', 'SortOrder')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Direct.].[Sites]', 'IsActive')
Insert into #ColumnsToSync (SyncTable, IdentityColumn) values ('[Direct.].[Sites]', 'SiteID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Profile.Data].[Publication.Type]', 'pubidtype_id')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Profile.Data].[Publication.Type]', 'name')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Profile.Data].[Publication.Type]', 'sort_order')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[Profile.Data].[Publication.MyPub.Category]', 'HmsPubCategory')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[Profile.Data].[Publication.MyPub.Category]', 'CategoryName')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_Permission]', 'PermissionScope')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_Permission]', 'PermissionDescription')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_Permission]', 'MethodAndRequest')
--Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORCID.].[REF_Permission]', 'PermissionID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORCID.].[REF_Permission]', 'SuccessMessage')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORCID.].[REF_Permission]', 'FailedMessage')
--Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_PersonStatusType]', 'PersonStatusTypeID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_PersonStatusType]', 'StatusDescription')
--Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_WorkExternalType]', 'WorkExternalTypeID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_WorkExternalType]', 'WorkExternalType')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORCID.].[REF_WorkExternalType]', 'WorkExternalDescription')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_RecordStatus]', 'StatusDescription')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORCID.].[REF_RecordStatus]', 'RecordStatusID')
--Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_Decision]', 'DecisionID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[REF_Decision]', 'DecisionDescription')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORCID.].[REF_Decision]', 'DecisionDescriptionLong')
--Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[RecordLevelAuditType]', 'RecordLevelAuditTypeID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[RecordLevelAuditType]', 'AuditType')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORCID.].[DefaultORCIDDecisionIDMapping]', 'SecurityGroupID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORCID.].[DefaultORCIDDecisionIDMapping]', 'DefaultORCIDDecisionID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORNG.].[Apps]', 'AppID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORNG.].[Apps]', 'Name')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[Apps]', 'URL')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[Apps]', 'PersonFilterID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[Apps]', 'RequiresRegistration')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[Apps]', 'UnavailableMessage')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[Apps]', 'OAuthSecret')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[Apps]', 'Enabled')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORNG.].[AppViews]', 'AppID')
Insert into #ColumnsToSync (SyncTable, IndexColumn) values ('[ORNG.].[AppViews]', 'Page')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[AppViews]', '[View]')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[AppViews]', 'ChromeID')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[AppViews]', 'Visibility')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[AppViews]', 'DisplayOrder')
Insert into #ColumnsToSync (SyncTable, SyncColumn) values ('[ORNG.].[AppViews]', 'OptParams')
; with columns as (
select '[' + s.name + '].[' + o.name + ']' as tableName, c.name as columnName, t.name as typeName, c.is_nullable as nullable from sys.columns c join sys.objects o
on o.object_id = c.object_id
join sys.schemas s
on o.schema_id = s.schema_id
join sys.types t
on c.user_type_id = t.user_type_id
), columnsWithTypes as (
select * from #ColumnsToSync cts join columns c
on cts.SyncTable = c.tableName
and (cts.IndexColumn = c.columnName or cts.SyncColumn = c.columnName or cts.IdentityColumn = c.columnName)
)
select SyncTable,
IndexColumn,
SyncColumn,
typeName,
nullable,
identityColumn,
'((old.' + IndexColumn + ' is null and new.' + IndexColumn + ' is null) or (old.' + IndexColumn + ' is not null and new.' + IndexColumn + ' is not null and old.' + IndexColumn + ' = new.' + IndexColumn + '))'
as IndexColumnCompare,
case when typename in ('xml', 'text') then '((old.' + SyncColumn + ' is null and new.' + SyncColumn + ' is not null) or (old.' + SyncColumn + ' is not null and new.' + SyncColumn + ' is null) or (old.' + SyncColumn + ' is not null and new.' + SyncColumn + ' is not null and cast(old.' + SyncColumn + ' as nvarchar(max)) <> cast(new.' + SyncColumn + ' as nvarchar(max))))'
else '((old.' + SyncColumn + ' is null and new.' + SyncColumn + ' is not null) or (old.' + SyncColumn + ' is not null and new.' + SyncColumn + ' is null) or (old.' + SyncColumn + ' is not null and new.' + SyncColumn + ' is not null and old.' + SyncColumn + ' <> new.' + SyncColumn + '))'
end as SyncColumnCompare,
--xml cast(isnull([table].CustomEditModule, '') as nvarchar(max))
case when typeName in ('varchar', 'nvarchar', 'char') then 'isnull(''''''''+ replace([table].' + IndexColumn + ','''''''', '''''''''''')+'''''''', ''null'')'
when typeName in ('int', 'bit', 'bigint', 'float', 'tinyint') then 'isnull(cast([table].' + IndexColumn + ' as nvarchar(max)), ''null'')'
when typeName in ('xml', 'text') then 'isnull(''''''''+ replace(cast([table].' + IndexColumn + ','''''''', '''''''''''') as nvarchar(max)) +'''''''', ''null'')'
else null
end as IndexColumnCastAsNVarchar,
case when typeName in ('varchar', 'nvarchar', 'char') then 'isnull(''''''''+ replace([table].' + SyncColumn + ','''''''', '''''''''''')+'''''''', ''null'')'
when typeName in ('int', 'bit', 'bigint', 'float', 'tinyint') then 'isnull(cast([table].' + SyncColumn + ' as nvarchar(max)), ''null'')'
when typeName in ('xml', 'text') then 'isnull(''''''''+ replace(cast([table].' + SyncColumn + ' as nvarchar(max)),'''''''', '''''''''''') +'''''''', ''null'')'
else null
end as SyncColumnCastAsNVarchar,
case when typeName in ('varchar', 'nvarchar', 'char') then 'case when ' + IndexColumn + ' is null then ''' + IndexColumn + ' is null'' else ''' + IndexColumn + '= '''''' + replace(' + IndexColumn + ','''''''', '''''''''''') + '''''''' end '
when typeName in ('int', 'bit', 'bigint', 'float', 'tinyint') then 'case when ' + IndexColumn + ' is null then ''' + IndexColumn + ' is null'' else ''' + IndexColumn + '= '' + cast(' + IndexColumn + ' as nvarchar(max)) + '''' end '
when typeName in ('xml', 'text') then 'case when ' + IndexColumn + 'is null then ''' + IndexColumn + ' is null'' else ''' + IndexColumn + '= '''''' + ' + IndexColumn + ' + '''''''' end '
else null
end as IndexColumnUpdate,
case when typeName in ('varchar', 'nvarchar', 'char') then 'case when old.' + IndexColumn + ' is null then ''' + IndexColumn + ' is null'' else ''' + IndexColumn + '= '''''' + replace(old.' + IndexColumn + ','''''''', '''''''''''') + '''''''' end '
when typeName in ('int', 'bit', 'bigint', 'float', 'tinyint') then 'case when old.' + IndexColumn + ' is null then ''' + IndexColumn + ' is null'' else ''' + IndexColumn + '= '' + cast(old.' + IndexColumn + ' as nvarchar(max)) + '''' end '
when typeName in ('xml', 'text') then 'case when ' + IndexColumn + 'is null then ''old.' + IndexColumn + ' is null'' else ''' + IndexColumn + '= '''''' + old.' + IndexColumn + ' + '''''''' end '
else null
end as IndexColumnDelete,
case when typeName in ('varchar', 'nvarchar', 'char') then 'case when ' + syncColumn + '_changed = 1 then '' ' + syncColumn + ' = ''''''+ replace(' + syncColumn + ','''''''', '''''''''''') +'''''','' else '''' end'
when typeName in ('int', 'bit', 'bigint', 'float', 'tinyint') then 'case when ' + syncColumn + '_changed = 1 then '' ' + syncColumn + ' = ''+ cast(' + syncColumn + ' as nvarchar(max)) + '','' else '''' end'
when typeName in ('xml', 'text') then 'case when ' + syncColumn + '_changed = 1 then '' ' + syncColumn + ' = '''''' + cast(' + syncColumn + ' as nvarchar(max)) +'''''','' else '''' end'
else null
end as SyncColumnUpdate
into #columnsWithCompareStrings from columnsWithTypes
-- select * from #ColumnsToSync where identitycolumn is not null
-- select * from #columnsWithCompareStrings where synctable like '%bot%'
select * into #tablesWithCompareStrings
From
(
Select distinct ST2.SyncTable, '#' + replace(replace(replace(ST2.SyncTable, '[', ''), ']', ''),'.', '_') as tmpTableName,
(
Select ST1.IndexColumnCompare + ' and ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
) [joinOn],
(
Select 'new.' + ST1.IndexColumn + ' is null and ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[newIsNull],
(
Select 'old.' + ST1.IndexColumn + ' is null and ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[oldIsNull],
(
Select ST1.SyncColumnCompare + ' OR ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[changedRows],
(
Select 'Case when ' + ST1.SyncColumnCompare + ' then 1 else 0 end as ' + ST1.SyncColumn + '_changed, ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[changedRowsDetail],
(
Select ST1.IndexColumn + ', ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[indexColumns],
(
Select 'new.' + ST1.IndexColumn + ', ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[newIndexColumns],
(
Select ST1.SyncColumn + ', ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[syncColumns],
(
Select 'new.' + ST1.SyncColumn + ', ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[newSyncColumns],
(
Select ' + ' + IndexColumnCastAsNVarchar + '+'', ''' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[indexValues],
(
Select ' + ' + SyncColumnCastAsNVarchar + '+'', ''' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[syncValues],
(
Select ST1.IndexColumnUpdate + ' + '' and '' + ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[indexColumnsUpdate],
(
Select ST1.SyncColumnUpdate + ' + ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[syncColumnsUpdate],
(
Select ST1.IndexColumnDelete + ' + '' and '' + ' AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)[indexColumnsDelete],
(
Select ST1.identityColumn AS [text()]
From #columnsWithCompareStrings ST1
Where ST1.SyncTable = ST2.SyncTable
ORDER BY ST1.SyncTable
For XML PATH ('')
)identityColumn,
cast ('' as nvarchar(max)) as changedRowTmpTableSelect,
cast ('' as nvarchar(max)) as changedRowUpdateStmt,
cast ('' as nvarchar(max)) as newRowsInsertStmt,
cast ('' as nvarchar(max)) as deletedRowDeleteStmt
From #columnsWithCompareStrings ST2
) [Main]
/*
Declare @oldDB varchar(255) = 'Profiles_2_0_0'
select SyncTable,
'Select * from ' + SyncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + LEFT([oldIsNull], len([oldIsNull]) - 4) as AddedRows,
'Select ''insert into '+ SyncTable + ' ( ' + indexColumns + Left(syncColumns, len(syncColumns) - 1) + ') values (''' + replace([indexValues], '[table]', 'new') + replace(LEFT([syncValues], len([syncValues]) - 5), '[table]', 'new') + '+'')'''
+ ' from ' + SyncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + LEFT([oldIsNull], len([oldIsNull]) - 4) as AddedRows,
'Select * from ' + SyncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + LEFT([newIsNull], len([newIsNull]) - 4) as DeletedRows,
'Select * from ' + SyncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + replace(replace(LEFT([changedRows], len([changedRows]) - 3), '<', '<'), '>', '>') as DeletedRow
from #tablesWithCompareStrings
*/
/*
Declare @oldDB varchar(255) = 'Profiles_2_0_0'
select synctable, tmpTableName, syncColumnsUpdate,'select ' + newIndexColumns + syncColumns + replace(replace(LEFT(changedRowsDetail, len(changedRowsDetail) - 1), '<', '<'), '>', '>')
+ ' into ' + tmpTableName + ' from ' + syncTable + ' new join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + replace(replace(LEFT(changedRows, len(changedRows) - 3), '<', '<'), '>', '>') as changedRows
from #tablesWithCompareStrings
*/
Declare @oldDB varchar(255) = 'Profiles_2_0_0'
update #tablesWithCompareStrings set changedRowTmpTableSelect = 'select ' + newIndexColumns + newSyncColumns + replace(replace(LEFT(changedRowsDetail, len(changedRowsDetail) - 1), '<', '<'), '>', '>')
+ ' into ' + tmpTableName + ' from ' + syncTable + ' new join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + replace(replace(LEFT(changedRows, len(changedRows) - 3), '<', '<'), '>', '>') where syncColumns <> ''
/*
select 'Select ''update ' + syncTable + ' set '' + replace(' + syncColumnsUpdate + ' + ''nwbreptxt'', '',nwbreptxt'', '''')' + ' + '' where '' + ' + left(indexColumnsUpdate, len(indexColumnsUpdate) - 13) + ' from ' + tmpTableName
from #tablesWithCompareStrings
select * From #tablesWithCompareStrings where syncColumns = ''
*/
update #tablesWithCompareStrings set changedRowUpdateStmt = 'Select ''' + syncTable + ''', ''update ' + syncTable + ' set '' + replace(' + syncColumnsUpdate + ' + ''nwbreptxt'', '',nwbreptxt'', '''')' + ' + '' where '' + ' + left(indexColumnsUpdate, len(indexColumnsUpdate) - 13) + ' from ' + tmpTableName
where syncColumns <> ''
update #tablesWithCompareStrings set newRowsInsertStmt =
'Select ''' + syncTable + ''', ''insert into '+ SyncTable + ' ( ' + identityColumn + ',' + indexColumns + Left(syncColumns, len(syncColumns) - 1) + ')
select '' + ' + '''max(' + identityColumn + ') + 1, ''' +
replace([indexValues], '[table]', 'new') + replace(LEFT([syncValues], len([syncValues]) - 5), '[table]', 'new') + ' +'' from '+ SyncTable +''''
+ ' from ' + SyncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + LEFT([oldIsNull], len([oldIsNull]) - 4)
where syncColumns <> '' and identityColumn <> ''
update #tablesWithCompareStrings set newRowsInsertStmt =
'Select ''' + syncTable + ''', ''insert into '+ SyncTable + ' ( ' + indexColumns + Left(syncColumns, len(syncColumns) - 1) + ')
values ('' + ' + replace([indexValues], '[table]', 'new') + replace(LEFT([syncValues], len([syncValues]) - 5), '[table]', 'new') + '+'')'''
+ ' from ' + SyncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + LEFT([oldIsNull], len([oldIsNull]) - 4)
where syncColumns <> '' and identityColumn = ''
update #tablesWithCompareStrings set newRowsInsertStmt =
'Select ''' + syncTable + ''', ''insert into '+ SyncTable + ' ( ' + Left(indexColumns, len(indexColumns) - 1) + ') values (''' + replace(LEFT([indexValues], len(indexValues) - 5), '[table]', 'new') + '+'')'''
+ ' from ' + SyncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + LEFT([oldIsNull], len([oldIsNull]) - 4)
where syncColumns = ''
update #tablesWithCompareStrings set deletedRowDeleteStmt =
'select ''' + syncTable + ''', ''delete from ' + SyncTable + ' where '' + ' + left(indexColumnsDelete, len(indexColumnsDelete) - 13) + ' from ' + syncTable + ' new full outer join ' + @oldDB + '.' + SyncTable + ' old on ' + LEFT(joinon, len(joinon) - 4)
+ ' where ' + LEFT([newIsNull], len([newIsNull]) - 4)
create table #updateQueries (
tableName nvarchar(max),
query nvarchar(max)
)
--select * from #updateQueries
--truncate table #updateQueries
Declare @sql nvarchar(MAX)
Declare @update1 nvarchar(MAX)
Declare @update2 nvarchar(MAX)
Declare @update3 nvarchar(MAX)
Declare @insert1 nvarchar(MAX)
Declare @delete1 nvarchar(MAX)
DECLARE db_cursor CURSOR FOR
SELECT changedRowTmpTableSelect, changedRowUpdateStmt, tmpTableName, newRowsInsertStmt, deletedRowDeleteStmt
FROM #tablesWithCompareStrings
OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @update1, @update2, @update3, @insert1, @delete1
WHILE @@FETCH_STATUS = 0
BEGIN
if @update1 <> ''
begin
select @sql = @update1 + '; insert into #updateQueries (tableName, query) ' + @update2 + '; drop table ' + @update3
exec sp_executesql @stmt = @sql
end
select @sql = 'insert into #updateQueries (tableName, query) ' + @insert1
exec sp_executesql @stmt = @sql
select @sql = 'insert into #updateQueries (tableName, query) ' + @delete1
exec sp_executesql @stmt = @sql
FETCH NEXT FROM db_cursor INTO @update1, @update2, @update3, @insert1, @delete1
END
CLOSE db_cursor
DEALLOCATE db_cursor
select * from #updateQueries order by TableName, query
/**
-- Delete Temp tables
drop table #ColumnsToSync
drop table #columnsWithCompareStrings
drop table #tablesWithCompareStrings
drop table #updateQueries
**/
select 'EXEC sp_fkeys ''' + SyncTable + '''' from #tablesWithCompareStrings
EXEC sp_fkeys '[Direct.].[Sites]'
EXEC sp_fkeys '[Framework.].[Job]'
EXEC sp_fkeys '[Framework.].[JobGroup]'
EXEC sp_fkeys '[Framework.].[Parameter]'
EXEC sp_fkeys '[Framework.].[RestPath]'
EXEC sp_fkeys '[Ontology.].[ClassGroup]'
EXEC sp_fkeys '[Ontology.].[ClassGroupClass]'
EXEC sp_fkeys '[Ontology.].[ClassProperty]'
EXEC sp_fkeys '[Ontology.].[DataMap]'
EXEC sp_fkeys '[Ontology.].[Namespace]'
EXEC sp_fkeys '[Ontology.].[PropertyGroup]'
EXEC sp_fkeys '[Ontology.].[PropertyGroupProperty]'
EXEC sp_fkeys '[Ontology.Presentation].[XML]'
EXEC sp_fkeys '[ORCID.].[DefaultORCIDDecisionIDMapping]'
EXEC sp_fkeys '[ORCID.].[RecordLevelAuditType]'
EXEC sp_fkeys '[ORCID.].[REF_Decision]'
EXEC sp_fkeys '[ORCID.].[REF_Permission]'
EXEC sp_fkeys '[ORCID.].[REF_PersonStatusType]'
EXEC sp_fkeys '[ORCID.].[REF_RecordStatus]'
EXEC sp_fkeys '[ORCID.].[REF_WorkExternalType]'
EXEC sp_fkeys '[ORNG.].[Apps]'
EXEC sp_fkeys '[ORNG.].[AppViews]'
EXEC sp_fkeys '[Profile.Data].[Publication.MyPub.Category]'
EXEC sp_fkeys '[Profile.Data].[Publication.Type]'
EXEC sp_fkeys '[RDF.Security].[Group]'
EXEC sp_fkeys '[User.Session].[Bot]'
EXEC sp_fkeys '[Utility.NLP].[ParsePorterStemming]'
EXEC sp_fkeys '[Utility.NLP].[StopWord]'
EXEC sp_fkeys '[Utility.NLP].[Thesaurus.Source]'
select * from sys.foreign_key_columns
/*
; with columns as (
select '[' + s.name + '].[' + o.name + ']' as tableName, c.name as columnName, t.name as typeName, c.is_nullable as nullable from sys.columns c join sys.objects o
on o.object_id = c.object_id
join sys.schemas s
on o.schema_id = s.schema_id
join sys.types t
on c.user_type_id = t.user_type_id
), columnsWithTypes as (
select * from #ColumnsToSync cts join columns c
on cts.SyncTable = c.tableName
and (cts.IndexColumn = c.columnName or cts.SyncColumn = c.columnName or cts.IdentityColumn = c.columnName)
)
*/
;with tables as (
select '[' + s.name + '].[' + o.name + ']' as tableName, o.object_id from sys.objects o
join sys.schemas s
on o.schema_id = s.schema_id
join #tablesWithCompareStrings t
on '[' + s.name + '].[' + o.name + ']' = t.SyncTable
)
select tc.tableName as constraintTable, tr.tableName as referencedTable from sys.foreign_key_columns c
join tables tc on parent_object_id = tc.object_id
join tables tr on referenced_object_id = tr.object_id
select * from sys.foreign_key_columns
select '[' + s.name + '].[' + o.name + ']' as tableName, o.object_id from sys.objects o
join sys.schemas s
on o.schema_id = s.schema_id
join #tablesWithCompareStrings t
on '[' + s.name + '].[' + o.name + ']' = t.SyncTable
/**
drop from constraint table
drop from referenced table
Update references table
update constraint table
insert into referenced tab