-
Notifications
You must be signed in to change notification settings - Fork 10
/
YourSQLDba_InstallOrUpdateScript.sql
16985 lines (15175 loc) · 651 KB
/
YourSQLDba_InstallOrUpdateScript.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
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
-- Copyright 2008 Maurice Pelchat
-- YourSQLDba : Auto-maintenance tools for SQL Server Databases
-- Author : Maurice Pelchat
-- GitHub Website Readme : https://github.com/pelsql/YourSqlDba#readme
-- Online Documentation : https://github.com/pelsql/YourSqlDba?tab=readme-ov-file#links-into-online-documentation
-- Latest release of YourSqlDba : https://github.com/pelsql/YourSqlDba/blob/master/YourSQLDba_InstallOrUpdateScript.sql?raw=true
-- First install? Easy setup to make YourSqlDba run with SQL Agent and Database Mail https://github.com/pelsql/YourSqlDba?tab=readme-ov-file#installinitialsetupofyoursqldba
-- Main entry point for maintenance https://github.com/pelsql/YourSqlDba?tab=readme-ov-file#maintyoursqldba_domaint
-- Job reporting and diagnostic : https://github.com/pelsql/YourSqlDba/?tab=readme-ov-file#mainthistoryview
-- More on diagnostics : https://github.com/pelsql/YourSqlDba/?tab=readme-ov-file#more-on-diagnostics
-- Version History : https://github.com/pelsql/YourSqlDba/?tab=readme-ov-file#version-history
Drop Table if Exists #version
create table #Version (version nvarchar(40), VersionDate datetime)
set nocount on
insert into #Version Values ('7.0.0.4', convert(datetime, '2024-12-20', 120))
--Alter database yoursqldba set single_user with rollback immediate
--go
--Alter database yoursqldba set multi_user
--go
--use tempdb
--go
--RESTORE DATABASE [YourSQLDba] FROM DISK = N'C:\Users\pelchat\Desktop\YourSQLDba_[2012-09-13_01h44m26_Jeu]_database.Bak' WITH FILE = 1, MOVE N'YourSQLDba' TO N'C:\isql2008r2\DBData\YourSQLDba.MDF', MOVE N'YourSQLDbaDb_Log' TO N'C:\isql2008r2\DBLogs\YourSQLDba_Log.LDF', NOUNLOAD, STATS = 10
--GO
declare @sql nvarchar(max); set @sql =
'
------------------------------------------------------------------------------------
YourSQLDba : Auto-maintenance tools for SQL Server Databases
Author : Maurice Pelchat
Contributors : Danielle Paquette-Harvey, Pierre-Luc Denommé, Dominic Perreault
Licence : LGPL http://www.opensource.org/licenses/lgpl-2.1.php
See point 15. of the licence described to the link above about warranty.
------------------------------------------------------------------------------------
YourSQLDba : Outils de maintenance de bases de données pour SQL Server
Auteur : Maurice Pelchat
Contributeurs : Danielle Paquette-Harvey, Pierre-Luc Denommé, Dominic Perreault
License : LGPL http://www.opensource.org/licenses/lgpl-2.1.php
Voir point 15. de la licence décrite au lien ci-dessus concernant la garantie.
------------------------------------------------------------------------------------
'
set @sql = replace(@sql, '"', '''')
print @sql
-- If YourSqlDba.Do_Maint is actually running wait until it ends, and prevent it
-- to run until this script is done. We don't want to break running code
-- when replacing SQL Modules with new versions
Use tempdb
If DB_ID('YourSqlDba') IS NOT NULL
Begin
set nocount on
Set @Sql =
N'
Use YourSqlDba
declare @cnt int =1
While (1=1)
Begin
If APPLOCK_TEST ("public", "YourSqlDba.Do_Maint", "Exclusive", "Session")=1
Break
Raiserror ("Waiting for YourSqlDba.Do_maint to terminate...", 0, 1) with nowait
Select "Check messages for more info: Waiting for YourSqlDba.Do_maint to terminate..., "
Waitfor Delay "00:00:01" -- wait a sec, some msg are out
End
'
Set @Sql=replace(@sql collate database_default,'"','''')
Exec (@Sql)
End
Use tempdb
--
-- Installation procedure
--
-- Step 1 : Simply launch this script, it install YourSQLDba database and objects requiered for maintenance
-- Step 2 : ON FIRST INSTALL ONLY, run YourSQLDba_SetupOf_SqlAgent_MaintenanceJobs_DatabaseMail.
-- This script setup SQLAgent Tasks, Database Mail
-- using supplied parameters.
-- Example for it is supplied at the end of this script.
-- First two parameters are backups directories for log and for complete database backups
-- Thrid parameter is email of the database admin or other operator
-- Forth parameter is the address or name of a mail server that will
-- accept anonymous smtp from your sql server (from database mail).
--
-- Upgrades : Just rerun the new version of the script as described in Step 1 only
--
-- Customizations are possible int the SQL Agent Job generated by the setup.
-- Maintenance parameters are customizable at the job step level.
-- Once defined, more steps can be added to the job with different parameters for different databases sets
-- More steps can be added for operating systems commands especially to move backups files
--
-- =====================================================================================================
-- *****************************************************************************************************
-- FOR CONTRIBUTORS
--
-- You can send your comments and/or source code to pelsql@hotmail.com
--
-- Any upgrades must take into account that the script must finds itself the state of the current
-- installed version and bring it to the latest version (the actual script).
--
-- Samples of this process are kept from previous version as if it ever existed
-- but because of translation to identifiers in english, this version never really existed.
--
-- However the method proove to be 100% successful with the previous french version.
-- Many users of the original version upgraded their solution without problem and from any previous version
--
-- It helped very much in making the project easy to upgrade, as it is always the same :
-- re-run the latest script to upgrade to the last version.
--
-- *****************************************************************************************************
-- For users of previous version set new solution to 'YourSQLDba' database
declare @msg nvarchar(max) = NULL
;With Coll(name) as (select convert(sysname, SERVERPROPERTY('Collation')))
select @Msg = 'YourSqlDba doesn''t supported servers with case sensitive or binary collations '
From Coll Where name Like '%[_]CS[_]%' Or name Like '%[_]BIN'
if @msg IS NOT NULL
Raiserror (@Msg, 25,1) WITH LOG
GO
If not exists
(
select *
from sys.configurations
Where name = 'show advanced options'
And value_in_use = 1
)
Begin
EXEC sp_configure 'show advanced options', 1
Reconfigure
End
GO
If not exists
(
select *
from sys.configurations
Where name = 'allow updates'
And value_in_use = 0
)
Begin
EXEC sp_configure 'allow updates', 0
Reconfigure
End
GO
If not exists
(
select *
from sys.configurations
Where name = 'clr enabled'
And value_in_use = 1
)
Begin
Exec sp_configure 'clr enabled', 1
End
GO
If not exists
(
select *
from sys.configurations
Where name = 'Agent XPs'
And value_in_use = 1
)
Begin
EXEC sp_configure 'Agent XPs', 1
Reconfigure with override
End
GO
-- Adjust SQL Server error logs archive to maximum of 30 error log cycle (by reboot or explicitely asked daily by YourSqlDba)
Set nocount On
EXEC xp_instance_regwrite N'HKEY_LOCAL_MACHINE', N'Software\Microsoft\MSSQLServer\MSSQLServer', N'NumErrorLogs', REG_DWORD, 30
GO
-- If Sql Service Broker in not enabled on MSDB, enable it
if exists(select name, is_broker_enabled from sys.databases where name = 'msdb' and is_broker_enabled = 0)
begin
print 'Sql Service broker activation in MSDB'
exec('alter database msdb set enable_broker with ROLLBACK IMMEDIATE')
end
-- else
-- print 'Broker already enabled on MSDB'
GO
If Db_name() <> 'TempDb' Use TempDb;
GO
-- ****************************************************************************************************
-- Save actual copy of YourSqlDba, in case a rollback is needed or past yoursqldba logs would be useful
-- ****************************************************************************************************
If databasepropertyEx('YourSQLDba','status') IS NOT NULL -- db is there
Begin
-- save data about some YourSqlDba tables
Drop table if Exists ##JobHistory;
Drop table if Exists ##JobHistoryDetails;
Drop Table if Exists ##JobHistoryLineDetails; -- instead of presenting event info in XML, it is presented in readable form
Drop table if Exists ##JobLastBkpLocations;
Drop table if Exists ##TargetServer;
Drop table if Exists ##JobSeqUpdStat;
Drop table if Exists ##NetworkDrivesToSetOnStartup;
-- perform some cleanup for YourSqlDba Maint.JobHistory table
While (1=1)
Begin
Print 'Cleanup YourSqlDba job history for jobs older than 30 days'
Delete top (50) H -- drop 50 jobs at the time to let the log file clear itself, cascading deletes does the rest of the job
From
(
Select distinct JobNo --
From YourSqlDba.Maint.JobHistory
Where JobStart < dateadd(dd, -30, getdate())
) as T
join
YourSqlDba.Maint.JobHistory H
On H.JobNo = T.JobNo
If @@rowcount = 0 Break
End
-- If table exists in previous version save its content
If Object_id('YourSqlDba.Maint.JobHistory') IS NOT NULL
Begin
Declare @JsonPrms Int, @colIdJsonPrms Int, @colIdMainSqlCmd Int
Exec sp_executeSql
N'Use YourSqlDba;
Set @colIdJsonPrms=Columnproperty(Object_id(''YourSqlDba.Maint.JobHistory''), ''JSonPrms'', ''ColumnId'')
Set @colIdMainSqlCmd=Columnproperty(Object_id(''YourSqlDba.Maint.JobHistory''), ''MainSqlCmd'', ''ColumnId'')
'
, N'@colIdJsonPrms Int Output, @colIdMainSqlCmd Int Output'
, @colIdJsonPrms Output
, @colIdMainSqlCmd Output
If @colIdJsonPrms IS NOT NULL -- table is up to date for column JsonPrms, make the copy of the table
Exec('Select * Into ##JobHistory From YourSqlDba.Maint.JobHistory')
Else
Exec( -- JsonPrms column is missing, brew the new version of the table with just JsonPrm
'
Select
JobNo
, JobStart
, JobEnd
, Spid
, JsonPrms=
(
Select
, JobName
, DoInteg, DoUpdStats, DoReorg, DoFullBkp, DoDiffBkp, DoLogBkp, JobName, JobStart, JobEnd
, IncDb, ExcDb, ExcDbFromPolicy_CheckFullRecoveryModel
, TimeStampNamingForBackups, FullBkpRetDays, LogBkpRetDays
, NotifyMandatoryFullDbBkpBeforeLogBkp
, SpreadUpdStatRun, SpreadCheckDb
, FullBackupPath, LogBackupPath,
, FullBkExt, LogBkExt,
, ConsecutiveDaysOfFailedBackupsToPutDbOffline
, MirrorServer
, MigrationTestMode
, ReplaceSrcBkpPathToMatchingMirrorPath
, ReplacePathsInDbFilenames
, JobId, StepId
, BkpLogsOnSameFile
, EncryptionAlgorithm, EncryptionCertificate
From YourSqlDba.Maint.JobHistory
For JSON PATH, WITHOUT_ARRAY_WRAPPER
)
Into ##JobHistory
From YourSqlDba.Maint.JobHistory
'
)
-- if column MainSqlCmd is missing add it also to the copy, assume other columns are missing since they are part of the same update
If @colIdMainSqlCmd IS NULL
Begin
alter table ##JobHistory add MainSqlCmd nvarchar(max) null
alter table ##JobHistory add Who Nvarchar(128) null
alter table ##JobHistory add Host Nvarchar(128) null
alter table ##JobHistory add Prog Nvarchar(128) null
alter table ##JobHistory add SqlAgentJobName Nvarchar(128) null
alter table ##JobHistory add jobId uniqueIdentifier Null
alter table ##JobHistory add StepId Int Null
End
End
-- make copies of other tables
If Object_id('YourSqlDba.Maint.JobHistoryDetails') IS NOT NULL
Select * Into ##JobHistoryDetails From YourSqlDba.Maint.JobHistoryDetails
If Object_id('YourSqlDba.Maint.JobHistoryLineDetails') IS NOT NULL
Select * Into ##JobHistoryLineDetails From YourSqlDba.Maint.JobHistoryLineDetails
If Object_id('YourSqlDba.Maint.JobLastBkpLocations') IS NOT NULL
Select * Into ##JobLastBkpLocations From YourSqlDba.Maint.JobLastBkpLocations
If Object_id('YourSqlDba.Mirroring.TargetServer') IS NOT NULL
Select * Into ##TargetServer From YourSqlDba.Mirroring.TargetServer
If Object_id('YourSqlDba.Maint.JobSeqUpdStat') IS NOT NULL
Select top 1 * Into ##JobSeqUpdStat From YourSqlDba.Maint.JobSeqUpdStat
If Object_id('YourSqlDba.Maint.NetworkDrivesToSetOnStartup') Is NOT NULL
Select * Into ##NetworkDrivesToSetOnStartup From YourSqlDba.Maint.NetworkDrivesToSetOnStartup
-- if database is not upgraded yet, do a save, but avoid if it is to the same version
If Not Exists(Select * from YourSqlDba.Install.VersionInfo () Actual join #Version NextVersion On Actual.VersionNumber = NextVersion.Version Collate database_default)
Begin
Declare @pathBkp Nvarchar(512);
Exec master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE'
, N'Software\Microsoft\MSSQLServer\MSSQLServer'
, N'BackupDirectory'
, @pathBkp OUTPUT
, 'no_output'
-- SAVING A BACKUP COPY OF YOURSQLDBA, BEFORE WIPING IT AND RECRATING IT
-- Don't use SaveDbOnNewFileSet but use "lighter" code to reduce code dependencies
Declare @Language nvarchar(512)
Exec YourSqlDba.yInstall.InstallationLanguage @language Output
If RIGHT(@pathBkp, 1) <> '\' Set @pathBkp = @pathBkp + '\'
Declare @bkpFile nvarchar(512)
Select @bkpFile = @pathBkp+'YourSqlDba_'+REPLACE(CONVERT(nvarchar, Getdate(), 120), ':', '_')+'.bak';
Declare @version nvarchar(10)
Select @version = VersionNumber From YourSqlDba.Install.VersionInfo ()
print '******************************************************************************************************************************'
print 'Saving a copy of version '+@version+' of YourSqlDba to ' + @bkpFile
print '******************************************************************************************************************************'
Declare @bkpName nvarchar(512)
Set @bkpName = 'Backup version '+@version+' of ' + @bkpFile
-- bkpName must be <= 128 otherwise it complains about data truncation in msdb backup history details
If len(@bkpName) > 128 Set @bkpName = Left(@bkpName, 125)+ '...'
Backup Database YourSqlDba To Disk = @bkpFile With Init, name = @bkpname
End
Exec ('Alter database YourSqlDba Set single_user with rollback immediate')
Exec ('WaitFor Delay ''00:00:05''; ')
Exec ('Drop database YourSqlDba')
End
Go
-- ------------------------------------------------------------------------------
-- Recreate a new YourSqlDba
-- ------------------------------------------------------------------------------
Declare @sql nvarchar(max)
Declare @pathData nvarchar(512)
Declare @pathLog nvarchar(512)
-- Read actual file locationof YourSqlDba if it exists and is available
;With
PathOfFileLocations as
(
select
reverse(Stuff(Reverse(Physical_Name), 1, charindex('\', Reverse(Physical_Name)), '')) collate database_default as path
, Case when Charindex(Name collate database_default, 'master, model, tempdb, msdb') > 0 Or Name like 'ReportServer%' Then 0 Else 1 End as SystemDb
, type
, database_id
, Case When database_Id = db_id('YourSqlDba') Then 1 Else 0 End as IsYourSqlDba -- to identify YourSqlDba files if its there
from sys.master_files
Where DatabasePropertyex(Db_name(Database_id), 'Status') = 'Online'
)
-- Select * From PathOfFileLocations
, EvalFileLocation as
(
Select path, IsYourSqlDba, Systemdb, type, Count (distinct database_id) Nb -- count by business cases, YourSqlDba first, then non system Db, then systemDb
From PathOfFileLocations
Group by path, IsYourSqlDba, SystemDb, type
)
--Select * From EvalFileLocation
, RankBestFileLocations as
(
Select
*
-- Rank best choice by : It is YourSqlDba actual location, non systemDb (0 before 1), and number of files
, Row_Number() Over (partition By type Order by IsYourSqlDba, systemDb, nb desc) as best
From EvalFileLocation
)
-- Select * From RankBestFileLocations
Select -- trick to select good values that comes from different rows, on a single result row
@pathData = max(case when type = 0 Then path else '' End)
, @pathLog = max(case when type = 1 Then path else '' End)
From RankBestFileLocations
Where best = 1
Set @sql =
'
Create Database YourSQLDba
ON PRIMARY
(
Name = "YourSQLDba",
FILENAME = "<pathData>\YourSQLDba.MDF",
SIZE = 60MB,
FILEGROWTH = 20MB
)
LOG ON
(
Name = "YourSQLDba_Log",
FILENAME = "<pathLog>\YourSQLDba_Log.LDF",
SIZE = 5MB,
FILEGROWTH = 5MB
)
COLLATE LATIN1_GENERAL_CI_AI
ALTER Database YourSQLDba Set RECOVERY SIMPLE
'
Set @sql = Replace (@sql, '"', '''')
Set @sql = Replace (@sql, '<pathData>', @pathData)
Set @sql = Replace (@sql, '<pathLog>', @pathLog)
Exec (@sql)
GO
-- Create YourSqlDba login, with unknown password. If required DBA can change it.
If not exists
(select * from sys.sql_logins where name='YourSQLDba')
Begin
declare @unknownPwd nvarchar(100) = convert(nvarchar(400), HASHBYTES('SHA1', convert(nvarchar(100),newid())), 2)
Exec
(
'
create login Yoursqldba
With Password = '''+@unknownPwd+'''
, DEFAULT_DATABASE = YourSqlDba
, CHECK_EXPIRATION = OFF
, CHECK_POLICY = OFF
, DEFAULT_LANGUAGE=US_ENGLISH
'
)
END
GO
Exec sp_addsrvrolemember @loginame= 'YourSqlDba' , @rolename = 'sysadmin'
GO
ALTER AUTHORIZATION ON Database::[YourSQLDba] To [YourSqlDba]
ALTER Database YourSqlDba Set TRUSTWORTHY ON
GO
If DB_NAME()<> 'YourSqlDba' Use YourSQLDba
--use tempdb
--GO
--alter database YourSQLDba set single_user with rollback immediate
--GO
--RESTORE DATABASE [YourSQLDba] FROM DISK = N'G:\SQL2005Backups\YourSQLDba_database[2][Mardi].Bak' WITH FILE = 1, NOUNLOAD, STATS = 5
--GO
-- create schemas to identify fonctions
Exec('Create schema Audit authorization dbo;')
Exec('Create schema yAudit authorization dbo;')
Exec('Create schema Export authorization dbo;')
Exec('Create schema yExport authorization dbo;')
Exec('CREATE SCHEMA yExecNLog AUTHORIZATION dbo')
Exec('Create schema Install authorization dbo;')
Exec('Create schema yInstall authorization dbo;')
Exec('Create schema Maint authorization dbo;')
Exec('Create schema yMaint authorization dbo;')
Exec('Create schema Mirroring authorization dbo;')
Exec('Create schema yMirroring authorization dbo;')
Exec('Create schema PerfMon authorization dbo;')
Exec('Create schema yPerfMon authorization dbo;')
Exec('CREATE SCHEMA Upgrade AUTHORIZATION dbo')
Exec('CREATE SCHEMA yUpgrade AUTHORIZATION dbo')
Exec('Create schema Tools authorization dbo;')
Exec('Create schema yUtl authorization dbo;')
Exec('Create schema S# authorization dbo;') -- for copying new code from S# library
GO
Create or Alter View Maint.MaintenanceEnums AS
Select
-- useful, general use constants to describe maintenance parameters
-- Those prefixed by HV$ are for function Maint.HistoryView
HV$ShowErrOnly = 1
, HV$ShowAll = 0
, HV$ShowOnlyErrorOfJobFromSessionContext = 2
, HV$Now
, HV$FromMidnight
, HV$FromYesterdayMidnight
, HV$Since12Hours
, HV$Since10Min
, HV$Since1Hour
From
(Select HV$Now=Getdate()) as Now
CROSS APPLY (Select HV$FromMidnight=DateAdd(Day, DateDiff(Day, 0, HV$Now), 0)) as FromMidnight
CROSS APPLY (Select HV$FromYesterdayMidnight=DateAdd(Day, DateDiff(Day, 0, HV$Now)-1, 0)) as FromYesterdayMidnight
CROSS APPLY (Select HV$Since12Hours=DateAdd(Hour, DateDiff(Hour, 0, HV$Now)-12, 0)) as Since12Hours
CROSS APPLY (Select HV$Since10min=DateAdd(Mi, DateDiff(Mi, 0, HV$Now)-10, 0)) as Since10Min
CROSS APPLY (Select HV$Since1Hour=DateAdd(hh, DateDiff(hh, 0, HV$Now)-1, 0)) as Since1Hour
GO
Create Or Alter View S#.Enums -- alter extra is allowed from SQL2016
as
Select
-- useful, general use constants to generate query or display them
cr
, Lf
, NL = cr+Lf
, SQuote=''''
, DQuote='"'
, Dot='.'
, SizesNameInNumbers.*
-- constants for S#.ScriptCodeToScriptRowData
, ScriptCodeToScriptRowData@InsertsFromAliasedVal = 1
, ScriptCodeToScriptRowData@InsertsFromValuesList = 2
, ScriptCodeToScriptRowData@SelectFromAliasedVal = 3
, ScriptCodeToScriptRowData@SelectFromValuesList = 4
, ScriptCodeToScriptRowData@CsvRows = 5
, ScriptCodeToScriptRowData@AddGo=99
-- constants for managing S#.ScriptManageEventSession
, ExtendedEventSession@Start = 1
, ExtendedEventSession@Stop = 2
, ExtendedEventSession@Clear = 3
-- Constants for Help Module
, Help@Keywords=0
, Help@ModuleNameOnly=1
, Help@AllInfo=2
-- Constants for
-- Constant for runScript
, RunScript@ErrMsgTemplate =
'----------------------------------------------------------------------------------------------
Error from S#.RunScript when running script above
----------------------------------------------------------------------------------------------
Msg: #ErrMessage#
Error: #ErrNumber# Severity: #ErrSeverity# State: #ErrState##atPos#
----------------------------------------------------------------------------------------------
'
From
(Select Cr = Nchar(13), Lf = Nchar(10)) as CrLf
-- real values in number of bytes or storage capacity names
Cross Apply
(
Select *
From
(Select KB=convert(bigInt,1024)) as Kb
cross apply (Select KiloByte=Kb) as KiloByte
cross apply (Select MB=Kb*kb) as Mb
cross apply (Select MegaByte=Mb) as MegaByte
cross apply (Select GB=Mb*kb) as Gb
cross apply (Select Gigabyte=Gb) as Gigabyte
cross apply (Select TB=Gb*Kb) as Tb
cross apply (Select Terabyte=Tb) as Terabyte
cross apply (Select PB=Tb*Kb) as Pb
cross apply (Select Petabyte=Pb) as Petabyte
cross apply (Select EB=Pb*Kb) as Eb
cross apply (Select ExaByte=Eb) as ExaByte
cross apply (Select ZB=Pb*Kb) as Zb
cross apply (Select ZettaByte=Zb) as ZettaByte
cross apply (Select YB=Pb*Kb) as Yb
cross apply (Select Yottabyte=Yb) as Yottabyte
) as SizesNameInNumbers
/*===Purpose===
This view is an handy way to define constants that define specific parameters
or more generally more useful constant. By cross joining this view, all constants
becomes accessible to queries using them, at no cost.
***BONUS***: When using S#.Enums intellisence helps to find constants
for a given module easily when they are in the form Modulename@option,
just by starting typing module name
===Purpose===*/
/*===Samples===
-- Run this sample by setting query results to text
-- When query results are in grid mode carriage return are invibible
-- but can be copied if SQL Server Management Studio options
-- \query results\Sql Server\Results to grid\Retain CR/LF on copy or save is checked
Select MultiLineText
From
S#.Enums -- to have access to "newline" Nl constant
CROSS APPLY (Select MultiLineText='First line'+Nl+'Second line'+Nl+'Third line'
===Samples===*/
/*===KeyWords===
Enumeration,constants,parameters
===KeyWords===*/
GO
Create Or Alter Function [S#].[GetCmtBetweenDelim] (@delim sysname, @ModuleRef Sql_Variant)
Returns table
as
-----------------------------------------------------------------------------------------------
-- Get text between start /*Delim and Delim*/ where Delim is a parameter
-- from source text which can
-- be the current batch is @moduleRef is NULL
-- the calling query if moduleRef = ''
-- the definition of the function/view/proc for which moduleRef is a name (varchar)
-- the definition of the function/view/proc for which object_id passed as a parameter
-----------------------------------------------------------------------------------------------
Return
(
Select *
From
(Select Delim=@delim, ModuleRef=@ModuleRef) as ModuleRef
CROSS APPLY (Select Typ=IIF(ModuleRef IS NULL, NULL, sql_variant_property(ModuleRef, 'BaseType'))) as Typ
OUTER APPLY (Select PrmIsName=Convert(sysName,moduleRef) Where Typ = 'varchar') as PrmIsName
OUTER APPLY (Select ObjId=Convert(int, moduleRef) Where Typ = 'int') as ObjId
-- GET A MODULE NAME THROUGH OBJECT_ID or IF NAME EXACTLY in OBJECT REF
-- module name Will be null if moduleRef is set to NULL on purpose (get source text from running batch or proc)
-- or if invalid object id is passed
OUTER APPLY
(
Select moduleName=QuoteName(Object_Schema_name(ObjId))+'.'+QuoteName(Object_name(ObjId)) Where ObjId IS NOT NULL
UNION ALL
Select ModuleName=PrmIsName Where PrmIsName Is NOT NULL
) as ModuleName
-- select from three different methods to get source code text to parse.
-- source text can comme from : 1) a sql module, 2) The calling query, 3) from either the batch or the running proc
OUTER APPLY
(
-- The module text like a view or a inline function
-- SrcTxt can be NULL if ModuleName isn't NULL but do not exists (no valid object_id),
Select SrcTxt=OBJECT_DEFINITION(Object_Id(ModuleName)) collate database_default
Where Typ Is NOT NULL And ModuleName IS Not NULL And ModuleName <> ''
UNION ALL
-- The top call stack of calling SQL, when moduleName is an empty string
Select SrcTxt=event_info Collate Database_default From sys.dm_exec_input_buffer(@@spid, null)
Where Typ Is NOT NULL And ModuleName = '' And event_type = 'Language Event'
UNION ALL
-- the current batch, or the current bacth of a running stored proc, when moduleRef is NULL
-- when typ is NULL, this is because there is NULL for moduleRef param.
Select SrcTxt=qt.text Collate Database_default
From
sys.dm_exec_requests er
Cross Apply sys.dm_exec_sql_text(er.sql_handle) as qt
Where Typ IS Null And er.session_id = @@SPID
) as SrcTxt
CROSS APPLY (Select LgCt=LEN(Delim) ) as LgCt
-- if srcTxt is NULL, startIndex, EndIndex are going to be null and Found will be null
CROSS APPLY (Select StartIndex=charindex('/*'+Delim, SrcTxt)) As StartIndex
CROSS APPLY (Select EndIndex=charindex(Delim+'*/', SrcTxt)-1 ) as EndIndex
OUTER APPLY (Select Found=1 Where StartIndex>0 And EndIndex>0 And LgCt>0) as Found
OUTER APPLY -- compute returns when everything is ok
(
Select *
FROM
(Select StartP=StartIndex+LgCt+2 ) As StartP
CROSS APPLY (Select EndP=EndIndex ) as EndP
CROSS APPLY (Select DelimTxtFound=Cast(Substring(SrcTxt, StartP, EndP-StartP+1) as nvarchar(max))) as DelimTxtFound
Where Found=1
) as FoundOk
-- in case input is invalid as when start and/or end comment ar missing
CROSS JOIN (Select IdFct='!S#.GetCmtBetweenDelim: ') as IdFct
OUTER APPLY (Select InvalidDelimMsg=IdFct+'Comment Delim is null!' Where Delim is NULL) as InvalidDelimMsg
OUTER APPLY
(
Select InvalidModuleMsg=IdFct+'No text to search because inexisting module'+moduleName+'!'
Where found IS NULL And PrmIsName IS NOT NULL And SrcTxt IS NULL
UNION ALL
Select InvalidModuleMsg=IdFct+'No text to search because inexisting module id '+CONVERT(nvarchar, ObjId)+'!'
Where found IS NULL And Typ = 'Int' And SrcTxt is NULL
) as InvalidModuleMsg
OUTER APPLY (Select NotFoundMsg=IdFct+'No comment text between start Delim /*'+Delim+' and end Delim '+Delim+'*/!' Where found IS NULL) as NotFound
CROSS APPLY (Select TxtInCmt=Coalesce(InvalidDelimMsg, InvalidModuleMsg, NotFoundMsg, DelimTxtFound)) as ResGet
/*===Purpose===
This function is to get some SQL Code wrapped in a multiline
comment that must starts and ends by a Delim of your choice
/*"Delim"
and end by
"Delim"*/
It simplifies coding of code definition or code template
instead of using litteral strings by having not to care about quotes.
The comment may be extracted depending @Moduleref Sql_Variant parameter from:
■ The running batch or directly in a stored procedure.
■ @@ProcId (id of the running SP)
■ Any SQL module name including itself (like a stored proc, function, Trigger Or View)
■ The topmost calling SQL (ex: a comment in the batch starting before the called stored proc)
This function have a very extensive use in this library!
===Purpose===*/
-- Test code to Keep!
--Select Sql
--From
-- (
-- Select FctName=QuoteName(Object_schema_name(Object_id))+'.'+QuoteName(Object_name(Object_id)), type_desc, type
-- From Sys.Objects
-- Where type_desc like '%Function%' And Type_Desc Not like 'Clr%'
-- ) As FctName
-- Cross Apply S#.GetCmtBetweenDelim('===DropAllFct===', NULL) As C
-- /*===DropAllFct===
-- Drop Function if exists #FctName#
-- ===DropAllFct===*/
-- CROSS Apply (Select Sql=Replace(C.TxtInCmt, '#FctName#', FctName)) as Sql
--go
---------------------------------------------------------------------------
--Drop Function if exists dbo.ScriptFunctionDrops
--go
--Create Or Alter Function dbo.ScriptFunctionDrops ()
--returns table
--as
--return
--Select Sql
--From
-- (
-- Select FctName=Object_schema_name(Object_id)+'.'+Object_name(Object_id), type_desc, type
-- From Sys.Objects
-- Where type_desc like '%Function%' And Type_Desc Not like 'Clr%'
-- And Object_id <> Object_Id('dbo.ScriptFunctionDrops') -- dont drop myself
-- ) As FctName
-- -- instead of null for @moduleRef, use self function name.
-- Cross Apply S#.GetCmtBetweenDelim('===DropAllFct===', 'dbo.ScriptFunctionDrops') As C
-- /*===DropAllFct===
-- Drop Function If exists #FctName#
-- ===DropAllFct===*/
-- CROSS Apply (Select Sql=Replace(C.TxtInCmt, '#FctName#', FctName)) as Sql
--go
--Select * from dbo.ScriptFunctionDrops()
--go
--Drop Function if exists dbo.ScriptFunctionDrops
--go
---------------------------------------------------------------------------
--drop Proc if exists dbo.DropsFunctions
--go
--Create Or Alter Proc dbo.DropsFunctions
--as
--Begin
-- Declare @Sql Nvarchar(max) = ''
-- Select @sql=@sql+Sql
-- From
-- (
-- Select FctName=Object_schema_name(Object_id)+'.'+Object_name(Object_id), type_desc, type
-- From Sys.Objects
-- Where type_desc like '%Function%' And Type_Desc Not like 'Clr%'
-- And Object_id <> Object_Id('dbo.DropsFunctions') -- dont drop myself
-- ) As FctName
-- -- instead of null for @moduleRef, use system variable that give current procedure id
-- Cross Apply S#.GetCmtBetweenDelim('===DropAllFct===', @@ProcId) As C
-- /*===DropAllFct===
-- Drop Function if exists #FctName#
-- ===DropAllFct===*/
-- CROSS Apply (Select Sql=Replace(C.TxtInCmt, '#FctName#', FctName)) as Sql
-- Print @Sql
--End
--go
--Exec dbo.DropsFunctions
--go
--Drop proc if exists dbo.DropsFunctions
--go
------------------------------------------------------------------------------------
---- KEEP THIS COMMENT, THIS IS A TEST ASSERTION FOR THIS FUNCTION
---- Test fail When this bunch of select + union all are selected and executed and returns something
---- Every select has a fail condition which resolves to true is the result is incorrect
---------------------------------------------------------------------------------------
--Select Test=1, * from S#.GetCmtBetweenDelim (NULL, 'S#.GetCmtBetweenDelim')
--Where isnull(TxtInCmt,'') <> '!S#.GetCmtBetweenDelim: Comment Delim is null!'
--union all
--Select Test=2,* from S#.GetCmtBetweenDelim ('Haha', NULL) /*HeheTextBetweenHehe*/
---- not like with ____ to avoid finding itself in where condition
--Where isnull(TxtInCmt,'') not like '!S#.GetCmtBetweenDelim: No comment text between start Delim /*____ and end Delim ____*/!'
--union all
--Select Test=3,* from S#.GetCmtBetweenDelim ('Haha', 'S#.GetCmtBetweenDelim') /*HeheTextBetweenHehe*/
---- not like with ____ to avoid finding itself in where condition
--Where isnull(TxtInCmt,'') not like '!S#.GetCmtBetweenDelim: No comment text between start Delim /*____ and end Delim ____*/!'
--union all
--Select Test=4,* from S#.GetCmtBetweenDelim ('Hehe', NULL) /*HeheTextBetweenHehe*/
--Where isnull(TxtInCmt,'') <> 'TextBetween'
--union all
--Select Test=5,* from S#.GetCmtBetweenDelim ('Hehe', 'S#.GetCmtBetweenDelim')
--Where isnull(TxtInCmt,'') <> 'TextBetween'
-------------------------------------------------------------------------------------------------------------
) --S#.GetCmtBetweenDelim
GO
Create Or Alter Function S#.ConcatFromJson(@InitSeparator nvarchar(10), @Separator nvarchar(10), @json nvarchar(max)) -- makes concat easier to do
Returns Table
As
Return
-----------------------------------------------------------------------------------------------------
-- this fonction accept muti-row of a single column values put in a Json Auto with optional order
-- expression to concat extract them with openjson and concat them using an XML expression.
-- some escaped char have to be removed because they are created by the XML concat expression
--
-- There is 3 parameters, Initial separator which replace separator on the first row value
-- If initial separator is NULL, separator is used everywhere, initial separator is the same as separator
-- if initial separator is non-null, it replace first separator by its value
-----------------------------------------------------------------------------------------------------
(
Select result
From
(Select Separator=ISNULL(@Separator,''), J=@json) as Prm0
-- no initSeparator, take same value as separator
CROSS APPLY (Select InitSeparator=ISNULL(@InitSeparator, Prm0.Separator), Prm0.J) as Prm
-- SQL do not mesure trailings spaces in LEN function, so add an extra non space char, mesure this len minus one.
CROSS APPLY (Select LenInitSeparator=LEN(InitSeparator+'|')-1) as LenInitSeparator
CROSS APPLY (Select lenSeparator=LEN(Separator+'|')-1) LenSeparator
-- concat everything with separator, so initSeparator is not there yet, separator is at its place
CROSS APPLY
(
Select
allConcat=
(
Select isnull(Separator,'') +Conc.Col as [text()]
From (Select * From openJson(Prm0.j) with (Col nvarchar(max))) as Conc
For XML Path(''),TYPE).value -- ,TYPE).value('.','NVARCHAR(MAX)') allow to make no escapes for ' " < > & in result
('.','NVARCHAR(MAX)')
) As allConcat
-- cases to deal with
-- separator is empty string if @separator is null, and initSeparator is the same as separator, if InitSeparator is null
-- InitSeparator isn't null, remove start of string of the len of Separator, and put InitSeparator instead as first separator
-- Shortcut job work, if there is no sep, job done
Outer Apply (Select ConcatAllNoSep=allConcat Where InitSeparator = '' And Separator = '') as ConcatAllNoSep
-- otherwise Handle initialSeparator
OUTER Apply (Select ConcatAllButFirst=STUFF(allConcat, 1, LenSeparator, InitSeparator) Where ConcatAllNoSep Is NULL) as ConcatAllButFirst
CROSS APPLY (Select Result=COALESCE(ConcatAllNoSep, ConcatAllButFirst)) as Result
/*-- some test
Select J1.result, ExpectedRes, ok, Test=IIf(ok=1, 'Success', 'Fail')+' for '+TestName, ColsTbInJson, InitSep, Sep, Expected
From
(Values ('Set1')) as S(SetN)
cross join (Select Nl=char(13)+CHAR(10)) as Nl
cross apply
(
Select
ColsTbInJson=
(
Select Col=item+NL
From (Values ('Set1', 'Select item1&', 1), ('Set1', 'Select [item2]<', 2), ('Set1', 'Select {item3}"', 3)) as t(setN, item, ord)
Where t.setN=S.setN
order by ord
FOR Json auto
)
) as x
CROSS APPLY -- parameter for cases to test, and expected result
(
Select *
From
(
Values
(NULL , NULL , 'Select item1&\nSelect [item2]<\nSelect {item3}"\n' , 'Null separators, so no sep between them')
, (NULL , ', ' , ', Select item1&\n, Select [item2]<\n, Select {item3}"\n' , 'NULL Initial separator, separator initial separator = separator')
, (' ' , 'Union all ' , ' Select item1&\nUnion all Select [item2]<\nUnion all Select {item3}"\n' , 'some initial separator to substitute to first occurence of separator' )
) as t(initSep, Sep , Expected , TestName)
CROSS APPLY (Select expectedRes=REPLACE(expected, '\n', NL)) as ExpectedRes
) TestData
Cross apply S#.ConcatFromJson(initSep, Sep, colsTbInJson) as J1
Outer apply (select Ok=1 Where result=ExpectedRes) as Ok
-- end of test cases
*/
/*===KeyWords===
Scripting
===KeyWords===*/
) -- S#.ConcatFromJson
GO
-- --------------------------------------------------------------------------
-- very useful function for turning templates into real code
-- json tags are expressed as #JsonTagName# and replaced by their json values
-- --------------------------------------------------------------------------
Create Or Alter Function S#.MultipleReplaces (@Template nvarchar(max), @JsonDataSource Nvarchar(max))
Returns Table
as
Return
---
--- JSON support makes Dbo.ReplaceTagsMatchingXMLAttributesNamesByTheirValue obsolete.
--- This version does the same thing faster.
---
-- keep this commented code below to test inner working of the query
--
--declare @JsonDataSource as nvarchar(max) =
--'
--[
-- {
-- "TbName": "[S#].[RealRestoreFileListOnly]",
-- "Cols": " [spid] int NULL Default (@@spid)\n, [LogicalName] nvarchar(128) NULL\n, [PhysicalName] nvarchar(260) NULL\n, [Type] nchar(1) NULL\n, [FileGroupName] nvarchar(128) NULL\n, [Size] numeric(20, 0) NULL\n, [MaxSize] numeric(20, 0) NULL\n, [FileID] bigint NULL\n, [CreateLSN] numeric(25, 0) NULL\n, [DropLSN] numeric(25, 0) NULL\n, [UniqueID] uniqueidentifier NULL\n, [ReadOnlyLSN] numeric(25, 0) NULL\n, [ReadWriteLSN] numeric(25, 0) NULL\n, [BackupSizeInBytes] bigint NULL\n, [SourceBlockSize] int NULL\n, [FileGroupID] int NULL\n, [LogGroupGUID] uniqueidentifier NULL\n, [DifferentialBaseLSN] numeric(25, 0) NULL\n, [DifferentialBaseGUID] uniqueidentifier NULL\n, [IsReadOnly] bit NULL\n, [IsPresent] bit NULL\n, [TDEThumbprint] varbinary(32) NULL\n, [SnapshotURL] nvarchar(36) NULL\n"
-- },
-- {
-- "TbName": "[S#].[RealRestoreHeaderOnly]",
-- "Cols": " [spid] int NULL Default (@@spid)\n, [BackupName] nvarchar(128) NULL\n, [BackupDescription] nvarchar(255) NULL\n, [BackupType] smallint NULL\n, [ExpirationDate] datetime NULL\n, [Compressed] tinyint NULL\n, [Position] smallint NULL\n, [DeviceType] tinyint NULL\n, [UserName] nvarchar(128) NULL\n, [ServerName] nvarchar(128) NULL\n, [DatabaseName] nvarchar(128) NULL\n, [DatabaseVersion] int NULL\n, [DatabaseCreationDate] datetime NULL\n, [BackupSize] numeric(20, 0) NULL\n, [FirstLSN] numeric(25, 0) NULL\n, [LastLSN] numeric(25, 0) NULL\n, [CheckpointLSN] numeric(25, 0) NULL\n, [DatabaseBackupLSN] numeric(25, 0) NULL\n, [BackupStartDate] datetime NULL\n, [BackupFinishDate] datetime NULL\n, [SortOrder] smallint NULL\n, [CodePage] smallint NULL\n, [UnicodeLocaleId] int NULL\n, [UnicodeComparisonStyle] int NULL\n, [CompatibilityLevel] tinyint NULL\n, [SoftwareVendorId] int NULL\n, [SoftwareVersionMajor] int NULL\n, [SoftwareVersionMinor] int NULL\n, [SoftwareVersionBuild] int NULL\n, [MachineName] nvarchar(128) NULL\n, [Flags] int NULL\n, [BindingID] uniqueidentifier NULL\n, [RecoveryForkID] uniqueidentifier NULL\n, [Collation] nvarchar(128) NULL\n, [FamilyGUID] uniqueidentifier NULL\n, [HasBulkLoggedData] bit NULL\n, [IsSnapshot] bit NULL\n, [IsReadOnly] bit NULL\n, [IsSingleUser] bit NULL\n, [HasBackupChecksums] bit NULL\n, [IsDamaged] bit NULL\n, [BeginsLogChain] bit NULL\n, [HasIncompleteMetaData] bit NULL\n, [IsForceOffline] bit NULL\n, [IsCopyOnly] bit NULL\n, [FirstRecoveryForkID] uniqueidentifier NULL\n, [ForkPointLSN] numeric(25, 0) NULL\n, [RecoveryModel] nvarchar(60) NULL\n, [DifferentialBaseLSN] numeric(25, 0) NULL\n, [DifferentialBaseGUID] uniqueidentifier NULL\n, [BackupTypeDescription] nvarchar(60) NULL\n, [BackupSetGUID] uniqueidentifier NULL\n, [CompressedBackupSize] bigint NULL\n, [Containment] tinyint NULL\n, [KeyAlgorithm] nvarchar(32) NULL\n, [EncryptorThumbprint] varbinary(20) NULL\n, [EncryptorType] nvarchar(32) NULL\n"
-- },
-- {
-- "TbName": "[S#].[InstallYourSqlDba]",
-- "Cols": " [Version] varchar(7) Not NULL\n, [RevisionDate] date NULL\n"
-- },
-- {
-- "TbName": "[S#].[RealScriptToRun]",
-- "Cols": " [spid] int Not NULL Default (@@spid)\n, [nestLevel] int Not NULL Default (@@nestlevel)\n, [seq] int Not NULL\n, [eventTime] datetime2(7) NULL Default (sysdatetime())\n, [Sql] nvarchar(Max) NULL\n, [label] nvarchar(Max) NULL\n, [db] sysname NULL\n"
-- },
-- {
-- "TbName": "[S#].[ProcessMaintenancePrm]",
-- "Cols": " [PrmSetInJson] nvarchar(Max) NULL\n, [JsonJobStates] nvarchar(Max) NULL\n"
-- }
--]
--'
--Declare @template nvarchar(max)=
--'
--Create Table #TbName#
--(
--#Cols#)
--TEXTIMAGE_ON
--'
--;
With
TagSrc as
(
Select
RowKey
-- AttributeRowSeq is useful as it allows to specify a replace order from JsonDataSource attribute by relative position
-- example If tagSrc='This is #F#', and JsonDataSource contains '[{"F":"contains #b#","B":"b contains #c#,"C":"last"}]'
-- replace seq will be: 'This is #F#' -> 'This is contains #b#' -> 'This is contains last'
, AttributeRowSeq = Row_number() Over (Partition by Rowkey Order By Pos)
, AttributeNbOfRow = COUNT(*) Over (Partition by RowKey)
, AttributeTag = '#'+[Key]+'#' collate database_default
, AttributeValue = isnull(Value,'') collate database_default -- tags with no values are replaced by empty string
, rowvalue
From
(Select JsonDataSource=@JsonDataSource) as JsonDataSource
CROSS APPLY (select Rowkey=[key], RowValue=Value, Pos=CharIndex('"'+[Key]+'":', JsonDataSource) From openjson (JsonDataSource)) as Rows
cross apply openJson (RowValue)
)
, TagReplacements As
(
Select RowKey, AttributeRowSeq, AttributeNbOfRow, AttributeTag, AttributeValue, LastReplace=Cast (REPLACE (@template, AttributeTag, AttributeValue) as nvarchar(max))
From tagSrc Where AttributeRowSeq = 1
UNION ALL
Select T.Rowkey, T.AttributeRowSeq, T.AttributeNbOfRow, T.AttributeTag, T.AttributeValue, LastReplace=Cast (REPLACE (LastReplace, T.AttributeTag, T.AttributeValue) as nvarchar(max))
From
(Select Rowkey, LastReplace, LastAttributeRowSeq=AttributeRowSeq From TagReplacements) as Prev
JOIN TagSrc AS T
On T.RowKey = Prev.RowKey
And T.AttributeRowSeq = Prev.LastAttributeRowSeq+1
)
Select replacedTxt=LastReplace
from TagReplacements Where AttributeNbOfRow = AttributeRowSeq
/*======= some test example by calling the function itself ===============
Select replacedTxt
From
(
Select
jMain =
(
Select --- ********** if complex expressions are used it is important to put all columns
--- ********** at the same select level otherwise json will not be properly formatted by Auto option
TbName
, Cols
From
( -- choose table
Select TbName = Dbo.FullObjName (object_id)
From sys.tables
--Where Dbo.FullObjName (object_id) like '%realRestore%'
) as TbName
cross apply
(
Select
ColsTbInJson=
( -- get cols list and express it in json
Select Col=CI.ColDef+nchar(10)
From Dbo.ColInfo(TbName, NULL) as CI
order by Ci.ColOrd
FOR Json auto
)
) as x
-- concat cols content from Json expression, and make put comma in front of each except the first one
--cross apply (Select top 1 cols=j.CAT From Dbo.ConcatColFromJson('', ', ', colsTbInJson) as J) as cols
cross apply (Select Cols=convert(nvarchar(max),result) From S#.ConcatFromJson('', ', ', colsTbInJson)) as cols
For json Auto
)
) as V
cross apply
(
SELECT MainSyntaxTb.replacedTxt
From
(Select CreateTbTemplate=TxtInCmt From S#.GetCmtBetweenDelim ('===temp===', null)) as CreateTbTemplate
/*===temp===
Create Table #TbName#
(
#Cols#)
TEXTIMAGE_ON
===temp===*/
Cross Apply S#.MultipleReplaces(CreateTbTemplate, jMain) as MainSyntaxTb
) MainSyntaxTb
=================== end sample test =================================*/
/*===KeyWords===
Scripting
===KeyWords===*/
GO
-------------------------------------------------------------------------------------
-- combine two useful functions for code template processing
-- S#.GetCmtBetweenDelim and S#.MultipleReplaces
--
-- See @Delim parameter in S#.GetCmtBetweenDelim for more details
-- See @JsonDataSource parameter in S#.MultipleReplaces for more details
--
-- Find template code in comment by use of S#.GetCmtBetweenDelim
-- Process multiple replaces in the template code by use of S#.MultipleReplaces
--
-- This function is useful to get a template code from a comment and replace tags in it
-- @jSonDataSource is a json string that contains "tagName", "TagValue" pairs
-- tags are expressed as #TagName# in source code and are replaced by "TagValue"
-- It is cleaner to produce the @jsonDataSource with a cross apply query that returns
-- a single row with a single column in the form of
-- Cross Apply (select jsonDataSource=(Select * from (Values ('tag1', 'value1'), ('tag2', 'value2')) as t(tag, value) for json auto)) as JsonDataSource
-------------------------------------------------------------------------------------
Create Or Alter Function S#.GetTemplateFromCmtAndReplaceTags (@delim sysname, @CmtSource Sql_Variant, @JSonDataSource Nvarchar(max))
Returns table
As
Return
Select Code=Code.replacedTxt
From
S#.GetCmtBetweenDelim (@delim, @CmtSource) as Template
CROSS APPLY S#.MultipleReplaces (Template.TxtInCmt, @JsonDataSource) as Code
GO
-- -------------------------------------------------------------------------------------------------------------
-- Function return full object name of a specific object_id. Very useful to get fully qualified
-- object name from an object_id or from object_id function.
-- -------------------------------------------------------------------------------------------------------------
Create Or Alter Function S#.FullObjName
(
@object_id Int
)
Returns sysname
as
Begin
Return (QUOTENAME(object_schema_name(@Object_id))+'.' +QUOTENAME(object_name(@Object_Id)))