-
Notifications
You must be signed in to change notification settings - Fork 752
/
MaintenanceSolution.sql
9112 lines (7592 loc) · 451 KB
/
MaintenanceSolution.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
/*
SQL Server Maintenance Solution - SQL Server 2008, SQL Server 2008 R2, SQL Server 2012, SQL Server 2014, SQL Server 2016, SQL Server 2017, SQL Server 2019, and SQL Server 2022
Backup: https://ola.hallengren.com/sql-server-backup.html
Integrity Check: https://ola.hallengren.com/sql-server-integrity-check.html
Index and Statistics Maintenance: https://ola.hallengren.com/sql-server-index-and-statistics-maintenance.html
License: https://ola.hallengren.com/license.html
GitHub: https://github.com/olahallengren/sql-server-maintenance-solution
Version: 2024-10-27 11:48:54
You can contact me by e-mail at [email protected].
Ola Hallengren
https://ola.hallengren.com
*/
USE [master] -- Specify the database in which the objects will be created.
SET NOCOUNT ON
DECLARE @CreateJobs nvarchar(max) = 'Y' -- Specify whether jobs should be created.
DECLARE @BackupDirectory nvarchar(max) = NULL -- Specify the backup root directory. If no directory is specified, the default backup directory is used.
DECLARE @CleanupTime int = NULL -- Time in hours, after which backup files are deleted. If no time is specified, then no backup files are deleted.
DECLARE @OutputFileDirectory nvarchar(max) = NULL -- Specify the output file directory. If no directory is specified, then the SQL Server error log directory is used.
DECLARE @LogToTable nvarchar(max) = 'Y' -- Log commands to a table.
DECLARE @ErrorMessage nvarchar(max)
IF IS_SRVROLEMEMBER('sysadmin') = 0 AND NOT (DB_ID('rdsadmin') IS NOT NULL AND SUSER_SNAME(0x01) = 'rdsa')
BEGIN
SET @ErrorMessage = 'You need to be a member of the SysAdmin server role to install the SQL Server Maintenance Solution.'
RAISERROR(@ErrorMessage,16,1) WITH NOWAIT
END
IF NOT (SELECT [compatibility_level] FROM sys.databases WHERE database_id = DB_ID()) >= 90
BEGIN
SET @ErrorMessage = 'The database ' + QUOTENAME(DB_NAME(DB_ID())) + ' has to be in compatibility level 90 or higher.'
RAISERROR(@ErrorMessage,16,1) WITH NOWAIT
END
IF OBJECT_ID('tempdb..#Config') IS NOT NULL DROP TABLE #Config
CREATE TABLE #Config ([Name] nvarchar(max),
[Value] nvarchar(max))
INSERT INTO #Config ([Name], [Value]) VALUES('CreateJobs', @CreateJobs)
INSERT INTO #Config ([Name], [Value]) VALUES('BackupDirectory', @BackupDirectory)
INSERT INTO #Config ([Name], [Value]) VALUES('CleanupTime', @CleanupTime)
INSERT INTO #Config ([Name], [Value]) VALUES('OutputFileDirectory', @OutputFileDirectory)
INSERT INTO #Config ([Name], [Value]) VALUES('LogToTable', @LogToTable)
INSERT INTO #Config ([Name], [Value]) VALUES('DatabaseName', DB_NAME(DB_ID()))
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[CommandLog]') AND type in (N'U'))
BEGIN
CREATE TABLE [dbo].[CommandLog](
[ID] [int] IDENTITY(1,1) NOT NULL,
[DatabaseName] [sysname] NULL,
[SchemaName] [sysname] NULL,
[ObjectName] [sysname] NULL,
[ObjectType] [char](2) NULL,
[IndexName] [sysname] NULL,
[IndexType] [tinyint] NULL,
[StatisticsName] [sysname] NULL,
[PartitionNumber] [int] NULL,
[ExtendedInfo] [xml] NULL,
[Command] [nvarchar](max) NOT NULL,
[CommandType] [nvarchar](60) NOT NULL,
[StartTime] [datetime2](7) NOT NULL,
[EndTime] [datetime2](7) NULL,
[ErrorNumber] [int] NULL,
[ErrorMessage] [nvarchar](max) NULL,
CONSTRAINT [PK_CommandLog] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)
)
END
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[CommandExecute]') AND type in (N'P', N'PC'))
BEGIN
EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[CommandExecute] AS'
END
GO
ALTER PROCEDURE [dbo].[CommandExecute]
@DatabaseContext nvarchar(max),
@Command nvarchar(max),
@CommandType nvarchar(max),
@Mode int,
@Comment nvarchar(max) = NULL,
@DatabaseName nvarchar(max) = NULL,
@SchemaName nvarchar(max) = NULL,
@ObjectName nvarchar(max) = NULL,
@ObjectType nvarchar(max) = NULL,
@IndexName nvarchar(max) = NULL,
@IndexType int = NULL,
@StatisticsName nvarchar(max) = NULL,
@PartitionNumber int = NULL,
@ExtendedInfo xml = NULL,
@LockMessageSeverity int = 16,
@ExecuteAsUser nvarchar(max) = NULL,
@LogToTable nvarchar(max),
@Execute nvarchar(max)
AS
BEGIN
----------------------------------------------------------------------------------------------------
--// Source: https://ola.hallengren.com //--
--// License: https://ola.hallengren.com/license.html //--
--// GitHub: https://github.com/olahallengren/sql-server-maintenance-solution //--
--// Version: 2024-10-27 11:48:54 //--
----------------------------------------------------------------------------------------------------
SET NOCOUNT ON
DECLARE @StartMessage nvarchar(max)
DECLARE @EndMessage nvarchar(max)
DECLARE @ErrorMessage nvarchar(max)
DECLARE @ErrorMessageOriginal nvarchar(max)
DECLARE @Severity int
DECLARE @Errors TABLE (ID int IDENTITY PRIMARY KEY,
[Message] nvarchar(max) NOT NULL,
Severity int NOT NULL,
[State] int)
DECLARE @CurrentMessage nvarchar(max)
DECLARE @CurrentSeverity int
DECLARE @CurrentState int
DECLARE @sp_executesql nvarchar(max) = QUOTENAME(@DatabaseContext) + '.sys.sp_executesql'
DECLARE @StartTime datetime2
DECLARE @EndTime datetime2
DECLARE @ID int
DECLARE @Error int = 0
DECLARE @ReturnCode int = 0
DECLARE @EmptyLine nvarchar(max) = CHAR(9)
DECLARE @RevertCommand nvarchar(max)
----------------------------------------------------------------------------------------------------
--// Check core requirements //--
----------------------------------------------------------------------------------------------------
IF NOT (SELECT [compatibility_level] FROM sys.databases WHERE database_id = DB_ID()) >= 90
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The database ' + QUOTENAME(DB_NAME(DB_ID())) + ' has to be in compatibility level 90 or higher.', 16, 1
END
IF NOT (SELECT uses_ansi_nulls FROM sys.sql_modules WHERE [object_id] = @@PROCID) = 1
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'ANSI_NULLS has to be set to ON for the stored procedure.', 16, 1
END
IF NOT (SELECT uses_quoted_identifier FROM sys.sql_modules WHERE [object_id] = @@PROCID) = 1
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'QUOTED_IDENTIFIER has to be set to ON for the stored procedure.', 16, 1
END
IF @LogToTable = 'Y' AND NOT EXISTS (SELECT * FROM sys.objects objects INNER JOIN sys.schemas schemas ON objects.[schema_id] = schemas.[schema_id] WHERE objects.[type] = 'U' AND schemas.[name] = 'dbo' AND objects.[name] = 'CommandLog')
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The table CommandLog is missing. Download https://ola.hallengren.com/scripts/CommandLog.sql.', 16, 1
END
----------------------------------------------------------------------------------------------------
--// Check input parameters //--
----------------------------------------------------------------------------------------------------
IF @DatabaseContext IS NULL OR NOT EXISTS (SELECT * FROM sys.databases WHERE name = @DatabaseContext)
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @DatabaseContext is not supported.', 16, 1
END
IF @Command IS NULL OR @Command = ''
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @Command is not supported.', 16, 1
END
IF @CommandType IS NULL OR @CommandType = '' OR LEN(@CommandType) > 60
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @CommandType is not supported.', 16, 1
END
IF @Mode NOT IN(1,2) OR @Mode IS NULL
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @Mode is not supported.', 16, 1
END
IF @LockMessageSeverity NOT IN(10,16) OR @LockMessageSeverity IS NULL
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @LockMessageSeverity is not supported.', 16, 1
END
IF LEN(@ExecuteAsUser) > 128
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @ExecuteAsUser is not supported.', 16, 1
END
IF @LogToTable NOT IN('Y','N') OR @LogToTable IS NULL
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @LogToTable is not supported.', 16, 1
END
IF @Execute NOT IN('Y','N') OR @Execute IS NULL
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @Execute is not supported.', 16, 1
END
----------------------------------------------------------------------------------------------------
--// Raise errors //--
----------------------------------------------------------------------------------------------------
DECLARE ErrorCursor CURSOR FAST_FORWARD FOR SELECT [Message], Severity, [State] FROM @Errors ORDER BY [ID] ASC
OPEN ErrorCursor
FETCH ErrorCursor INTO @CurrentMessage, @CurrentSeverity, @CurrentState
WHILE @@FETCH_STATUS = 0
BEGIN
RAISERROR('%s', @CurrentSeverity, @CurrentState, @CurrentMessage) WITH NOWAIT
RAISERROR(@EmptyLine, 10, 1) WITH NOWAIT
FETCH NEXT FROM ErrorCursor INTO @CurrentMessage, @CurrentSeverity, @CurrentState
END
CLOSE ErrorCursor
DEALLOCATE ErrorCursor
IF EXISTS (SELECT * FROM @Errors WHERE Severity >= 16)
BEGIN
SET @ReturnCode = 50000
GOTO ReturnCode
END
----------------------------------------------------------------------------------------------------
--// Execute as user //--
----------------------------------------------------------------------------------------------------
IF @ExecuteAsUser IS NOT NULL
BEGIN
SET @Command = 'EXECUTE AS USER = ''' + REPLACE(@ExecuteAsUser,'''','''''') + '''; ' + @Command + '; REVERT;'
SET @RevertCommand = 'REVERT'
END
----------------------------------------------------------------------------------------------------
--// Log initial information //--
----------------------------------------------------------------------------------------------------
SET @StartTime = SYSDATETIME()
SET @StartMessage = 'Date and time: ' + CONVERT(nvarchar,@StartTime,120)
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Database context: ' + QUOTENAME(@DatabaseContext)
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Command: ' + @Command
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
IF @Comment IS NOT NULL
BEGIN
SET @StartMessage = 'Comment: ' + @Comment
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
END
IF @LogToTable = 'Y'
BEGIN
INSERT INTO dbo.CommandLog (DatabaseName, SchemaName, ObjectName, ObjectType, IndexName, IndexType, StatisticsName, PartitionNumber, ExtendedInfo, CommandType, Command, StartTime)
VALUES (@DatabaseName, @SchemaName, @ObjectName, @ObjectType, @IndexName, @IndexType, @StatisticsName, @PartitionNumber, @ExtendedInfo, @CommandType, @Command, @StartTime)
END
SET @ID = SCOPE_IDENTITY()
----------------------------------------------------------------------------------------------------
--// Execute command //--
----------------------------------------------------------------------------------------------------
IF @Mode = 1 AND @Execute = 'Y'
BEGIN
EXECUTE @sp_executesql @stmt = @Command
SET @Error = @@ERROR
SET @ReturnCode = @Error
END
IF @Mode = 2 AND @Execute = 'Y'
BEGIN
BEGIN TRY
EXECUTE @sp_executesql @stmt = @Command
END TRY
BEGIN CATCH
SET @Error = ERROR_NUMBER()
SET @ErrorMessageOriginal = ERROR_MESSAGE()
SET @ErrorMessage = 'Msg ' + CAST(ERROR_NUMBER() AS nvarchar) + ', ' + ISNULL(ERROR_MESSAGE(),'')
SET @Severity = CASE WHEN ERROR_NUMBER() IN(1205,1222) THEN @LockMessageSeverity ELSE 16 END
RAISERROR('%s',@Severity,1,@ErrorMessage) WITH NOWAIT
IF NOT (ERROR_NUMBER() IN(1205,1222) AND @LockMessageSeverity = 10)
BEGIN
SET @ReturnCode = ERROR_NUMBER()
END
IF @ExecuteAsUser IS NOT NULL
BEGIN
EXECUTE @sp_executesql @RevertCommand
END
END CATCH
END
----------------------------------------------------------------------------------------------------
--// Log completing information //--
----------------------------------------------------------------------------------------------------
SET @EndTime = SYSDATETIME()
SET @EndMessage = 'Outcome: ' + CASE WHEN @Execute = 'N' THEN 'Not Executed' WHEN @Error = 0 THEN 'Succeeded' ELSE 'Failed' END
RAISERROR('%s',10,1,@EndMessage) WITH NOWAIT
SET @EndMessage = 'Duration: ' + CASE WHEN (DATEDIFF(SECOND,@StartTime,@EndTime) / (24 * 3600)) > 0 THEN CAST((DATEDIFF(SECOND,@StartTime,@EndTime) / (24 * 3600)) AS nvarchar) + '.' ELSE '' END + CONVERT(nvarchar,DATEADD(SECOND,DATEDIFF(SECOND,@StartTime,@EndTime),'1900-01-01'),108)
RAISERROR('%s',10,1,@EndMessage) WITH NOWAIT
SET @EndMessage = 'Date and time: ' + CONVERT(nvarchar,@EndTime,120)
RAISERROR('%s',10,1,@EndMessage) WITH NOWAIT
RAISERROR(@EmptyLine,10,1) WITH NOWAIT
IF @LogToTable = 'Y'
BEGIN
UPDATE dbo.CommandLog
SET EndTime = @EndTime,
ErrorNumber = CASE WHEN @Execute = 'N' THEN NULL ELSE @Error END,
ErrorMessage = @ErrorMessageOriginal
WHERE ID = @ID
END
ReturnCode:
IF @ReturnCode <> 0
BEGIN
RETURN @ReturnCode
END
----------------------------------------------------------------------------------------------------
END
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[DatabaseBackup]') AND type in (N'P', N'PC'))
BEGIN
EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[DatabaseBackup] AS'
END
GO
ALTER PROCEDURE [dbo].[DatabaseBackup]
@Databases nvarchar(max) = NULL,
@Directory nvarchar(max) = NULL,
@BackupType nvarchar(max),
@Verify nvarchar(max) = 'N',
@CleanupTime int = NULL,
@CleanupMode nvarchar(max) = 'AFTER_BACKUP',
@Compress nvarchar(max) = NULL,
@CopyOnly nvarchar(max) = 'N',
@ChangeBackupType nvarchar(max) = 'N',
@BackupSoftware nvarchar(max) = NULL,
@CheckSum nvarchar(max) = 'N',
@BlockSize int = NULL,
@BufferCount int = NULL,
@MaxTransferSize int = NULL,
@NumberOfFiles int = NULL,
@MinBackupSizeForMultipleFiles int = NULL,
@MaxFileSize int = NULL,
@CompressionLevel int = NULL,
@Description nvarchar(max) = NULL,
@Threads int = NULL,
@Throttle int = NULL,
@Encrypt nvarchar(max) = 'N',
@EncryptionAlgorithm nvarchar(max) = NULL,
@ServerCertificate nvarchar(max) = NULL,
@ServerAsymmetricKey nvarchar(max) = NULL,
@EncryptionKey nvarchar(max) = NULL,
@ReadWriteFileGroups nvarchar(max) = 'N',
@OverrideBackupPreference nvarchar(max) = 'N',
@NoRecovery nvarchar(max) = 'N',
@URL nvarchar(max) = NULL,
@Credential nvarchar(max) = NULL,
@MirrorDirectory nvarchar(max) = NULL,
@MirrorCleanupTime int = NULL,
@MirrorCleanupMode nvarchar(max) = 'AFTER_BACKUP',
@MirrorURL nvarchar(max) = NULL,
@AvailabilityGroups nvarchar(max) = NULL,
@Updateability nvarchar(max) = 'ALL',
@AdaptiveCompression nvarchar(max) = NULL,
@ModificationLevel int = NULL,
@LogSizeSinceLastLogBackup int = NULL,
@TimeSinceLastLogBackup int = NULL,
@DataDomainBoostHost nvarchar(max) = NULL,
@DataDomainBoostUser nvarchar(max) = NULL,
@DataDomainBoostDevicePath nvarchar(max) = NULL,
@DataDomainBoostLockboxPath nvarchar(max) = NULL,
@DirectoryStructure nvarchar(max) = '{ServerName}${InstanceName}{DirectorySeparator}{DatabaseName}{DirectorySeparator}{BackupType}_{Partial}_{CopyOnly}',
@AvailabilityGroupDirectoryStructure nvarchar(max) = '{ClusterName}${AvailabilityGroupName}{DirectorySeparator}{DatabaseName}{DirectorySeparator}{BackupType}_{Partial}_{CopyOnly}',
@FileName nvarchar(max) = '{ServerName}${InstanceName}_{DatabaseName}_{BackupType}_{Partial}_{CopyOnly}_{Year}{Month}{Day}_{Hour}{Minute}{Second}_{FileNumber}.{FileExtension}',
@AvailabilityGroupFileName nvarchar(max) = '{ClusterName}${AvailabilityGroupName}_{DatabaseName}_{BackupType}_{Partial}_{CopyOnly}_{Year}{Month}{Day}_{Hour}{Minute}{Second}_{FileNumber}.{FileExtension}',
@FileExtensionFull nvarchar(max) = NULL,
@FileExtensionDiff nvarchar(max) = NULL,
@FileExtensionLog nvarchar(max) = NULL,
@Init nvarchar(max) = 'N',
@Format nvarchar(max) = 'N',
@ObjectLevelRecoveryMap nvarchar(max) = 'N',
@ExcludeLogShippedFromLogBackup nvarchar(max) = 'Y',
@DirectoryCheck nvarchar(max) = 'Y',
@BackupOptions nvarchar(max) = NULL,
@StringDelimiter nvarchar(max) = ',',
@DatabaseOrder nvarchar(max) = NULL,
@DatabasesInParallel nvarchar(max) = 'N',
@LogToTable nvarchar(max) = 'N',
@Execute nvarchar(max) = 'Y'
AS
BEGIN
----------------------------------------------------------------------------------------------------
--// Source: https://ola.hallengren.com //--
--// License: https://ola.hallengren.com/license.html //--
--// GitHub: https://github.com/olahallengren/sql-server-maintenance-solution //--
--// Version: 2024-10-27 11:48:54 //--
----------------------------------------------------------------------------------------------------
SET NOCOUNT ON
DECLARE @StartMessage nvarchar(max)
DECLARE @EndMessage nvarchar(max)
DECLARE @DatabaseMessage nvarchar(max)
DECLARE @ErrorMessage nvarchar(max)
DECLARE @StartTime datetime2 = SYSDATETIME()
DECLARE @SchemaName nvarchar(max) = OBJECT_SCHEMA_NAME(@@PROCID)
DECLARE @ObjectName nvarchar(max) = OBJECT_NAME(@@PROCID)
DECLARE @VersionTimestamp nvarchar(max) = SUBSTRING(OBJECT_DEFINITION(@@PROCID),CHARINDEX('--// Version: ',OBJECT_DEFINITION(@@PROCID)) + LEN('--// Version: ') + 1, 19)
DECLARE @Parameters nvarchar(max)
DECLARE @HostPlatform nvarchar(max)
DECLARE @DirectorySeparator nvarchar(max)
DECLARE @Updated bit
DECLARE @Cluster nvarchar(max)
DECLARE @DefaultDirectory nvarchar(4000)
DECLARE @QueueID int
DECLARE @QueueStartTime datetime2
DECLARE @CurrentRootDirectoryID int
DECLARE @CurrentRootDirectoryPath nvarchar(4000)
DECLARE @CurrentDBID int
DECLARE @CurrentDatabaseName nvarchar(max)
DECLARE @CurrentDatabase_sp_executesql nvarchar(max)
DECLARE @CurrentUserAccess nvarchar(max)
DECLARE @CurrentIsReadOnly bit
DECLARE @CurrentDatabaseState nvarchar(max)
DECLARE @CurrentInStandby bit
DECLARE @CurrentRecoveryModel nvarchar(max)
DECLARE @CurrentDatabaseSize bigint
DECLARE @CurrentIsEncrypted bit
DECLARE @CurrentBackupType nvarchar(max)
DECLARE @CurrentMaxTransferSize int
DECLARE @CurrentNumberOfFiles int
DECLARE @CurrentFileExtension nvarchar(max)
DECLARE @CurrentFileNumber int
DECLARE @CurrentDifferentialBaseLSN numeric(25,0)
DECLARE @CurrentDifferentialBaseIsSnapshot bit
DECLARE @CurrentLogLSN numeric(25,0)
DECLARE @CurrentLatestBackup datetime2
DECLARE @CurrentDatabaseNameFS nvarchar(max)
DECLARE @CurrentDirectoryStructure nvarchar(max)
DECLARE @CurrentDatabaseFileName nvarchar(max)
DECLARE @CurrentMaxFilePathLength nvarchar(max)
DECLARE @CurrentFileName nvarchar(max)
DECLARE @CurrentDirectoryID int
DECLARE @CurrentDirectoryPath nvarchar(max)
DECLARE @CurrentFilePath nvarchar(max)
DECLARE @CurrentDate datetime2
DECLARE @CurrentCleanupDate datetime2
DECLARE @CurrentIsDatabaseAccessible bit
DECLARE @CurrentReplicaID uniqueidentifier
DECLARE @CurrentAvailabilityGroupID uniqueidentifier
DECLARE @CurrentAvailabilityGroup nvarchar(max)
DECLARE @CurrentAvailabilityGroupRole nvarchar(max)
DECLARE @CurrentAvailabilityGroupBackupPreference nvarchar(max)
DECLARE @CurrentIsPreferredBackupReplica bit
DECLARE @CurrentDatabaseMirroringRole nvarchar(max)
DECLARE @CurrentLogShippingRole nvarchar(max)
DECLARE @CurrentBackupSetID int
DECLARE @CurrentIsMirror bit
DECLARE @CurrentLastLogBackup datetime2
DECLARE @CurrentLogSizeSinceLastLogBackup float
DECLARE @CurrentAllocatedExtentPageCount bigint
DECLARE @CurrentModifiedExtentPageCount bigint
DECLARE @CurrentDatabaseContext nvarchar(max)
DECLARE @CurrentCommand nvarchar(max)
DECLARE @CurrentCommandOutput int
DECLARE @CurrentCommandType nvarchar(max)
DECLARE @Errors TABLE (ID int IDENTITY PRIMARY KEY,
[Message] nvarchar(max) NOT NULL,
Severity int NOT NULL,
[State] int)
DECLARE @CurrentMessage nvarchar(max)
DECLARE @CurrentSeverity int
DECLARE @CurrentState int
DECLARE @Directories TABLE (ID int PRIMARY KEY,
DirectoryPath nvarchar(max),
Mirror bit,
Completed bit)
DECLARE @URLs TABLE (ID int PRIMARY KEY,
DirectoryPath nvarchar(max),
Mirror bit)
DECLARE @DirectoryInfo TABLE (FileExists bit,
FileIsADirectory bit,
ParentDirectoryExists bit)
DECLARE @tmpDatabases TABLE (ID int IDENTITY,
DatabaseName nvarchar(max),
DatabaseNameFS nvarchar(max),
DatabaseType nvarchar(max),
AvailabilityGroup bit,
StartPosition int,
DatabaseSize bigint,
LogSizeSinceLastLogBackup float,
[Order] int,
Selected bit,
Completed bit,
PRIMARY KEY(Selected, Completed, [Order], ID))
DECLARE @tmpAvailabilityGroups TABLE (ID int IDENTITY PRIMARY KEY,
AvailabilityGroupName nvarchar(max),
StartPosition int,
Selected bit)
DECLARE @tmpDatabasesAvailabilityGroups TABLE (DatabaseName nvarchar(max),
AvailabilityGroupName nvarchar(max))
DECLARE @SelectedDatabases TABLE (DatabaseName nvarchar(max),
DatabaseType nvarchar(max),
AvailabilityGroup nvarchar(max),
StartPosition int,
Selected bit)
DECLARE @SelectedAvailabilityGroups TABLE (AvailabilityGroupName nvarchar(max),
StartPosition int,
Selected bit)
DECLARE @CurrentBackupOutput bit
DECLARE @CurrentBackupSet TABLE (ID int IDENTITY PRIMARY KEY,
Mirror bit,
VerifyCompleted bit,
VerifyOutput int)
DECLARE @CurrentDirectories TABLE (ID int PRIMARY KEY,
DirectoryPath nvarchar(max),
Mirror bit,
DirectoryNumber int,
CleanupDate datetime2,
CleanupMode nvarchar(max),
CreateCompleted bit,
CleanupCompleted bit,
CreateOutput int,
CleanupOutput int)
DECLARE @CurrentURLs TABLE (ID int PRIMARY KEY,
DirectoryPath nvarchar(max),
Mirror bit,
DirectoryNumber int)
DECLARE @CurrentFiles TABLE ([Type] nvarchar(max),
FilePath nvarchar(max),
Mirror bit)
DECLARE @CurrentCleanupDates TABLE (CleanupDate datetime2,
Mirror bit)
DECLARE @Error int = 0
DECLARE @ReturnCode int = 0
DECLARE @EmptyLine nvarchar(max) = CHAR(9)
DECLARE @Version numeric(18,10) = CAST(LEFT(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(max)),CHARINDEX('.',CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(max))) - 1) + '.' + REPLACE(RIGHT(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(max)), LEN(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(max))) - CHARINDEX('.',CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(max)))),'.','') AS numeric(18,10))
IF @Version >= 14
BEGIN
SELECT @HostPlatform = host_platform
FROM sys.dm_os_host_info
END
ELSE
BEGIN
SET @HostPlatform = 'Windows'
END
DECLARE @AmazonRDS bit = CASE WHEN DB_ID('rdsadmin') IS NOT NULL AND SUSER_SNAME(0x01) = 'rdsa' THEN 1 ELSE 0 END
----------------------------------------------------------------------------------------------------
--// Log initial information //--
----------------------------------------------------------------------------------------------------
SET @Parameters = '@Databases = ' + ISNULL('''' + REPLACE(@Databases,'''','''''') + '''','NULL')
SET @Parameters += ', @Directory = ' + ISNULL('''' + REPLACE(@Directory,'''','''''') + '''','NULL')
SET @Parameters += ', @BackupType = ' + ISNULL('''' + REPLACE(@BackupType,'''','''''') + '''','NULL')
SET @Parameters += ', @Verify = ' + ISNULL('''' + REPLACE(@Verify,'''','''''') + '''','NULL')
SET @Parameters += ', @CleanupTime = ' + ISNULL(CAST(@CleanupTime AS nvarchar),'NULL')
SET @Parameters += ', @CleanupMode = ' + ISNULL('''' + REPLACE(@CleanupMode,'''','''''') + '''','NULL')
SET @Parameters += ', @Compress = ' + ISNULL('''' + REPLACE(@Compress,'''','''''') + '''','NULL')
SET @Parameters += ', @CopyOnly = ' + ISNULL('''' + REPLACE(@CopyOnly,'''','''''') + '''','NULL')
SET @Parameters += ', @ChangeBackupType = ' + ISNULL('''' + REPLACE(@ChangeBackupType,'''','''''') + '''','NULL')
SET @Parameters += ', @BackupSoftware = ' + ISNULL('''' + REPLACE(@BackupSoftware,'''','''''') + '''','NULL')
SET @Parameters += ', @CheckSum = ' + ISNULL('''' + REPLACE(@CheckSum,'''','''''') + '''','NULL')
SET @Parameters += ', @BlockSize = ' + ISNULL(CAST(@BlockSize AS nvarchar),'NULL')
SET @Parameters += ', @BufferCount = ' + ISNULL(CAST(@BufferCount AS nvarchar),'NULL')
SET @Parameters += ', @MaxTransferSize = ' + ISNULL(CAST(@MaxTransferSize AS nvarchar),'NULL')
SET @Parameters += ', @NumberOfFiles = ' + ISNULL(CAST(@NumberOfFiles AS nvarchar),'NULL')
SET @Parameters += ', @MinBackupSizeForMultipleFiles = ' + ISNULL(CAST(@MinBackupSizeForMultipleFiles AS nvarchar),'NULL')
SET @Parameters += ', @MaxFileSize = ' + ISNULL(CAST(@MaxFileSize AS nvarchar),'NULL')
SET @Parameters += ', @CompressionLevel = ' + ISNULL(CAST(@CompressionLevel AS nvarchar),'NULL')
SET @Parameters += ', @Description = ' + ISNULL('''' + REPLACE(@Description,'''','''''') + '''','NULL')
SET @Parameters += ', @Threads = ' + ISNULL(CAST(@Threads AS nvarchar),'NULL')
SET @Parameters += ', @Throttle = ' + ISNULL(CAST(@Throttle AS nvarchar),'NULL')
SET @Parameters += ', @Encrypt = ' + ISNULL('''' + REPLACE(@Encrypt,'''','''''') + '''','NULL')
SET @Parameters += ', @EncryptionAlgorithm = ' + ISNULL('''' + REPLACE(@EncryptionAlgorithm,'''','''''') + '''','NULL')
SET @Parameters += ', @ServerCertificate = ' + ISNULL('''' + REPLACE(@ServerCertificate,'''','''''') + '''','NULL')
SET @Parameters += ', @ServerAsymmetricKey = ' + ISNULL('''' + REPLACE(@ServerAsymmetricKey,'''','''''') + '''','NULL')
SET @Parameters += ', @EncryptionKey = ' + ISNULL('''' + REPLACE(@EncryptionKey,'''','''''') + '''','NULL')
SET @Parameters += ', @ReadWriteFileGroups = ' + ISNULL('''' + REPLACE(@ReadWriteFileGroups,'''','''''') + '''','NULL')
SET @Parameters += ', @OverrideBackupPreference = ' + ISNULL('''' + REPLACE(@OverrideBackupPreference,'''','''''') + '''','NULL')
SET @Parameters += ', @NoRecovery = ' + ISNULL('''' + REPLACE(@NoRecovery,'''','''''') + '''','NULL')
SET @Parameters += ', @URL = ' + ISNULL('''' + REPLACE(@URL,'''','''''') + '''','NULL')
SET @Parameters += ', @Credential = ' + ISNULL('''' + REPLACE(@Credential,'''','''''') + '''','NULL')
SET @Parameters += ', @MirrorDirectory = ' + ISNULL('''' + REPLACE(@MirrorDirectory,'''','''''') + '''','NULL')
SET @Parameters += ', @MirrorCleanupTime = ' + ISNULL(CAST(@MirrorCleanupTime AS nvarchar),'NULL')
SET @Parameters += ', @MirrorCleanupMode = ' + ISNULL('''' + REPLACE(@MirrorCleanupMode,'''','''''') + '''','NULL')
SET @Parameters += ', @MirrorURL = ' + ISNULL('''' + REPLACE(@MirrorURL,'''','''''') + '''','NULL')
SET @Parameters += ', @AvailabilityGroups = ' + ISNULL('''' + REPLACE(@AvailabilityGroups,'''','''''') + '''','NULL')
SET @Parameters += ', @Updateability = ' + ISNULL('''' + REPLACE(@Updateability,'''','''''') + '''','NULL')
SET @Parameters += ', @AdaptiveCompression = ' + ISNULL('''' + REPLACE(@AdaptiveCompression,'''','''''') + '''','NULL')
SET @Parameters += ', @ModificationLevel = ' + ISNULL(CAST(@ModificationLevel AS nvarchar),'NULL')
SET @Parameters += ', @LogSizeSinceLastLogBackup = ' + ISNULL(CAST(@LogSizeSinceLastLogBackup AS nvarchar),'NULL')
SET @Parameters += ', @TimeSinceLastLogBackup = ' + ISNULL(CAST(@TimeSinceLastLogBackup AS nvarchar),'NULL')
SET @Parameters += ', @DataDomainBoostHost = ' + ISNULL('''' + REPLACE(@DataDomainBoostHost,'''','''''') + '''','NULL')
SET @Parameters += ', @DataDomainBoostUser = ' + ISNULL('''' + REPLACE(@DataDomainBoostUser,'''','''''') + '''','NULL')
SET @Parameters += ', @DataDomainBoostDevicePath = ' + ISNULL('''' + REPLACE(@DataDomainBoostDevicePath,'''','''''') + '''','NULL')
SET @Parameters += ', @DataDomainBoostLockboxPath = ' + ISNULL('''' + REPLACE(@DataDomainBoostLockboxPath,'''','''''') + '''','NULL')
SET @Parameters += ', @DirectoryStructure = ' + ISNULL('''' + REPLACE(@DirectoryStructure,'''','''''') + '''','NULL')
SET @Parameters += ', @AvailabilityGroupDirectoryStructure = ' + ISNULL('''' + REPLACE(@AvailabilityGroupDirectoryStructure,'''','''''') + '''','NULL')
SET @Parameters += ', @FileName = ' + ISNULL('''' + REPLACE(@FileName,'''','''''') + '''','NULL')
SET @Parameters += ', @AvailabilityGroupFileName = ' + ISNULL('''' + REPLACE(@AvailabilityGroupFileName,'''','''''') + '''','NULL')
SET @Parameters += ', @FileExtensionFull = ' + ISNULL('''' + REPLACE(@FileExtensionFull,'''','''''') + '''','NULL')
SET @Parameters += ', @FileExtensionDiff = ' + ISNULL('''' + REPLACE(@FileExtensionDiff,'''','''''') + '''','NULL')
SET @Parameters += ', @FileExtensionLog = ' + ISNULL('''' + REPLACE(@FileExtensionLog,'''','''''') + '''','NULL')
SET @Parameters += ', @Init = ' + ISNULL('''' + REPLACE(@Init,'''','''''') + '''','NULL')
SET @Parameters += ', @Format = ' + ISNULL('''' + REPLACE(@Format,'''','''''') + '''','NULL')
SET @Parameters += ', @ObjectLevelRecoveryMap = ' + ISNULL('''' + REPLACE(@ObjectLevelRecoveryMap,'''','''''') + '''','NULL')
SET @Parameters += ', @ExcludeLogShippedFromLogBackup = ' + ISNULL('''' + REPLACE(@ExcludeLogShippedFromLogBackup,'''','''''') + '''','NULL')
SET @Parameters += ', @DirectoryCheck = ' + ISNULL('''' + REPLACE(@DirectoryCheck,'''','''''') + '''','NULL')
SET @Parameters += ', @StringDelimiter = ' + ISNULL('''' + REPLACE(@StringDelimiter,'''','''''') + '''','NULL')
SET @Parameters += ', @DatabaseOrder = ' + ISNULL('''' + REPLACE(@DatabaseOrder,'''','''''') + '''','NULL')
SET @Parameters += ', @DatabasesInParallel = ' + ISNULL('''' + REPLACE(@DatabasesInParallel,'''','''''') + '''','NULL')
SET @Parameters += ', @LogToTable = ' + ISNULL('''' + REPLACE(@LogToTable,'''','''''') + '''','NULL')
SET @Parameters += ', @Execute = ' + ISNULL('''' + REPLACE(@Execute,'''','''''') + '''','NULL')
SET @StartMessage = 'Date and time: ' + CONVERT(nvarchar,@StartTime,120)
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Server: ' + CAST(SERVERPROPERTY('ServerName') AS nvarchar(max))
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Version: ' + CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(max))
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Edition: ' + CAST(SERVERPROPERTY('Edition') AS nvarchar(max))
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Platform: ' + @HostPlatform
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Procedure: ' + QUOTENAME(DB_NAME(DB_ID())) + '.' + QUOTENAME(@SchemaName) + '.' + QUOTENAME(@ObjectName)
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Parameters: ' + @Parameters
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Version: ' + @VersionTimestamp
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
SET @StartMessage = 'Source: https://ola.hallengren.com'
RAISERROR('%s',10,1,@StartMessage) WITH NOWAIT
RAISERROR(@EmptyLine,10,1) WITH NOWAIT
----------------------------------------------------------------------------------------------------
--// Check core requirements //--
----------------------------------------------------------------------------------------------------
IF NOT (SELECT [compatibility_level] FROM sys.databases WHERE database_id = DB_ID()) >= 90
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The database ' + QUOTENAME(DB_NAME(DB_ID())) + ' has to be in compatibility level 90 or higher.', 16, 1
END
IF NOT (SELECT uses_ansi_nulls FROM sys.sql_modules WHERE [object_id] = @@PROCID) = 1
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'ANSI_NULLS has to be set to ON for the stored procedure.', 16, 1
END
IF NOT (SELECT uses_quoted_identifier FROM sys.sql_modules WHERE [object_id] = @@PROCID) = 1
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'QUOTED_IDENTIFIER has to be set to ON for the stored procedure.', 16, 1
END
IF NOT EXISTS (SELECT * FROM sys.objects objects INNER JOIN sys.schemas schemas ON objects.[schema_id] = schemas.[schema_id] WHERE objects.[type] = 'P' AND schemas.[name] = 'dbo' AND objects.[name] = 'CommandExecute')
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The stored procedure CommandExecute is missing. Download https://ola.hallengren.com/scripts/CommandExecute.sql.', 16, 1
END
IF EXISTS (SELECT * FROM sys.objects objects INNER JOIN sys.schemas schemas ON objects.[schema_id] = schemas.[schema_id] WHERE objects.[type] = 'P' AND schemas.[name] = 'dbo' AND objects.[name] = 'CommandExecute' AND OBJECT_DEFINITION(objects.[object_id]) NOT LIKE '%@DatabaseContext%')
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The stored procedure CommandExecute needs to be updated. Download https://ola.hallengren.com/scripts/CommandExecute.sql.', 16, 1
END
IF @LogToTable = 'Y' AND NOT EXISTS (SELECT * FROM sys.objects objects INNER JOIN sys.schemas schemas ON objects.[schema_id] = schemas.[schema_id] WHERE objects.[type] = 'U' AND schemas.[name] = 'dbo' AND objects.[name] = 'CommandLog')
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The table CommandLog is missing. Download https://ola.hallengren.com/scripts/CommandLog.sql.', 16, 1
END
IF @DatabasesInParallel = 'Y' AND NOT EXISTS (SELECT * FROM sys.objects objects INNER JOIN sys.schemas schemas ON objects.[schema_id] = schemas.[schema_id] WHERE objects.[type] = 'U' AND schemas.[name] = 'dbo' AND objects.[name] = 'Queue')
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The table Queue is missing. Download https://ola.hallengren.com/scripts/Queue.sql.', 16, 1
END
IF @DatabasesInParallel = 'Y' AND NOT EXISTS (SELECT * FROM sys.objects objects INNER JOIN sys.schemas schemas ON objects.[schema_id] = schemas.[schema_id] WHERE objects.[type] = 'U' AND schemas.[name] = 'dbo' AND objects.[name] = 'QueueDatabase')
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The table QueueDatabase is missing. Download https://ola.hallengren.com/scripts/QueueDatabase.sql.', 16, 1
END
IF @@TRANCOUNT <> 0
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The transaction count is not 0.', 16, 1
END
IF @AmazonRDS = 1
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The stored procedure DatabaseBackup is not supported on Amazon RDS.', 16, 1
END
----------------------------------------------------------------------------------------------------
--// Select databases //--
----------------------------------------------------------------------------------------------------
SET @Databases = REPLACE(@Databases, CHAR(10), '')
SET @Databases = REPLACE(@Databases, CHAR(13), '')
WHILE CHARINDEX(@StringDelimiter + ' ', @Databases) > 0 SET @Databases = REPLACE(@Databases, @StringDelimiter + ' ', @StringDelimiter)
WHILE CHARINDEX(' ' + @StringDelimiter, @Databases) > 0 SET @Databases = REPLACE(@Databases, ' ' + @StringDelimiter, @StringDelimiter)
SET @Databases = LTRIM(RTRIM(@Databases));
WITH Databases1 (StartPosition, EndPosition, DatabaseItem) AS
(
SELECT 1 AS StartPosition,
ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @Databases, 1), 0), LEN(@Databases) + 1) AS EndPosition,
SUBSTRING(@Databases, 1, ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @Databases, 1), 0), LEN(@Databases) + 1) - 1) AS DatabaseItem
WHERE @Databases IS NOT NULL
UNION ALL
SELECT CAST(EndPosition AS int) + 1 AS StartPosition,
ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @Databases, EndPosition + 1), 0), LEN(@Databases) + 1) AS EndPosition,
SUBSTRING(@Databases, EndPosition + 1, ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @Databases, EndPosition + 1), 0), LEN(@Databases) + 1) - EndPosition - 1) AS DatabaseItem
FROM Databases1
WHERE EndPosition < LEN(@Databases) + 1
),
Databases2 (DatabaseItem, StartPosition, Selected) AS
(
SELECT CASE WHEN DatabaseItem LIKE '-%' THEN RIGHT(DatabaseItem,LEN(DatabaseItem) - 1) ELSE DatabaseItem END AS DatabaseItem,
StartPosition,
CASE WHEN DatabaseItem LIKE '-%' THEN 0 ELSE 1 END AS Selected
FROM Databases1
),
Databases3 (DatabaseItem, DatabaseType, AvailabilityGroup, StartPosition, Selected) AS
(
SELECT CASE WHEN DatabaseItem IN('ALL_DATABASES','SYSTEM_DATABASES','USER_DATABASES','AVAILABILITY_GROUP_DATABASES') THEN '%' ELSE DatabaseItem END AS DatabaseItem,
CASE WHEN DatabaseItem = 'SYSTEM_DATABASES' THEN 'S' WHEN DatabaseItem = 'USER_DATABASES' THEN 'U' ELSE NULL END AS DatabaseType,
CASE WHEN DatabaseItem = 'AVAILABILITY_GROUP_DATABASES' THEN 1 ELSE NULL END AvailabilityGroup,
StartPosition,
Selected
FROM Databases2
),
Databases4 (DatabaseName, DatabaseType, AvailabilityGroup, StartPosition, Selected) AS
(
SELECT CASE WHEN LEFT(DatabaseItem,1) = '[' AND RIGHT(DatabaseItem,1) = ']' THEN PARSENAME(DatabaseItem,1) ELSE DatabaseItem END AS DatabaseItem,
DatabaseType,
AvailabilityGroup,
StartPosition,
Selected
FROM Databases3
)
INSERT INTO @SelectedDatabases (DatabaseName, DatabaseType, AvailabilityGroup, StartPosition, Selected)
SELECT DatabaseName,
DatabaseType,
AvailabilityGroup,
StartPosition,
Selected
FROM Databases4
OPTION (MAXRECURSION 0)
IF @Version >= 11 AND SERVERPROPERTY('IsHadrEnabled') = 1
BEGIN
INSERT INTO @tmpAvailabilityGroups (AvailabilityGroupName, Selected)
SELECT name AS AvailabilityGroupName,
0 AS Selected
FROM sys.availability_groups
INSERT INTO @tmpDatabasesAvailabilityGroups (DatabaseName, AvailabilityGroupName)
SELECT databases.name,
availability_groups.name
FROM sys.databases databases
INNER JOIN sys.availability_replicas availability_replicas ON databases.replica_id = availability_replicas.replica_id
INNER JOIN sys.availability_groups availability_groups ON availability_replicas.group_id = availability_groups.group_id
END
INSERT INTO @tmpDatabases (DatabaseName, DatabaseNameFS, DatabaseType, AvailabilityGroup, [Order], Selected, Completed)
SELECT [name] AS DatabaseName,
RTRIM(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE([name],'\',''),'/',''),':',''),'*',''),'?',''),'"',''),'<',''),'>',''),'|','')) AS DatabaseNameFS,
CASE WHEN name IN('master','msdb','model') OR is_distributor = 1 THEN 'S' ELSE 'U' END AS DatabaseType,
NULL AS AvailabilityGroup,
0 AS [Order],
0 AS Selected,
0 AS Completed
FROM sys.databases
WHERE [name] <> 'tempdb'
AND source_database_id IS NULL
ORDER BY [name] ASC
UPDATE tmpDatabases
SET AvailabilityGroup = CASE WHEN EXISTS (SELECT * FROM @tmpDatabasesAvailabilityGroups WHERE DatabaseName = tmpDatabases.DatabaseName) THEN 1 ELSE 0 END
FROM @tmpDatabases tmpDatabases
UPDATE tmpDatabases
SET tmpDatabases.Selected = SelectedDatabases.Selected
FROM @tmpDatabases tmpDatabases
INNER JOIN @SelectedDatabases SelectedDatabases
ON tmpDatabases.DatabaseName LIKE REPLACE(SelectedDatabases.DatabaseName,'_','[_]')
AND (tmpDatabases.DatabaseType = SelectedDatabases.DatabaseType OR SelectedDatabases.DatabaseType IS NULL)
AND (tmpDatabases.AvailabilityGroup = SelectedDatabases.AvailabilityGroup OR SelectedDatabases.AvailabilityGroup IS NULL)
WHERE SelectedDatabases.Selected = 1
UPDATE tmpDatabases
SET tmpDatabases.Selected = SelectedDatabases.Selected
FROM @tmpDatabases tmpDatabases
INNER JOIN @SelectedDatabases SelectedDatabases
ON tmpDatabases.DatabaseName LIKE REPLACE(SelectedDatabases.DatabaseName,'_','[_]')
AND (tmpDatabases.DatabaseType = SelectedDatabases.DatabaseType OR SelectedDatabases.DatabaseType IS NULL)
AND (tmpDatabases.AvailabilityGroup = SelectedDatabases.AvailabilityGroup OR SelectedDatabases.AvailabilityGroup IS NULL)
WHERE SelectedDatabases.Selected = 0
UPDATE tmpDatabases
SET tmpDatabases.StartPosition = SelectedDatabases2.StartPosition
FROM @tmpDatabases tmpDatabases
INNER JOIN (SELECT tmpDatabases.DatabaseName, MIN(SelectedDatabases.StartPosition) AS StartPosition
FROM @tmpDatabases tmpDatabases
INNER JOIN @SelectedDatabases SelectedDatabases
ON tmpDatabases.DatabaseName LIKE REPLACE(SelectedDatabases.DatabaseName,'_','[_]')
AND (tmpDatabases.DatabaseType = SelectedDatabases.DatabaseType OR SelectedDatabases.DatabaseType IS NULL)
AND (tmpDatabases.AvailabilityGroup = SelectedDatabases.AvailabilityGroup OR SelectedDatabases.AvailabilityGroup IS NULL)
WHERE SelectedDatabases.Selected = 1
GROUP BY tmpDatabases.DatabaseName) SelectedDatabases2
ON tmpDatabases.DatabaseName = SelectedDatabases2.DatabaseName
IF @Databases IS NOT NULL AND (NOT EXISTS(SELECT * FROM @SelectedDatabases) OR EXISTS(SELECT * FROM @SelectedDatabases WHERE DatabaseName IS NULL OR DatabaseName = ''))
BEGIN
INSERT INTO @Errors ([Message], Severity, [State])
SELECT 'The value for the parameter @Databases is not supported.', 16, 1
END
----------------------------------------------------------------------------------------------------
--// Select availability groups //--
----------------------------------------------------------------------------------------------------
IF @AvailabilityGroups IS NOT NULL AND @Version >= 11 AND SERVERPROPERTY('IsHadrEnabled') = 1
BEGIN
SET @AvailabilityGroups = REPLACE(@AvailabilityGroups, CHAR(10), '')
SET @AvailabilityGroups = REPLACE(@AvailabilityGroups, CHAR(13), '')
WHILE CHARINDEX(@StringDelimiter + ' ', @AvailabilityGroups) > 0 SET @AvailabilityGroups = REPLACE(@AvailabilityGroups, @StringDelimiter + ' ', @StringDelimiter)
WHILE CHARINDEX(' ' + @StringDelimiter, @AvailabilityGroups) > 0 SET @AvailabilityGroups = REPLACE(@AvailabilityGroups, ' ' + @StringDelimiter, @StringDelimiter)
SET @AvailabilityGroups = LTRIM(RTRIM(@AvailabilityGroups));
WITH AvailabilityGroups1 (StartPosition, EndPosition, AvailabilityGroupItem) AS
(
SELECT 1 AS StartPosition,
ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @AvailabilityGroups, 1), 0), LEN(@AvailabilityGroups) + 1) AS EndPosition,
SUBSTRING(@AvailabilityGroups, 1, ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @AvailabilityGroups, 1), 0), LEN(@AvailabilityGroups) + 1) - 1) AS AvailabilityGroupItem
WHERE @AvailabilityGroups IS NOT NULL
UNION ALL
SELECT CAST(EndPosition AS int) + 1 AS StartPosition,
ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @AvailabilityGroups, EndPosition + 1), 0), LEN(@AvailabilityGroups) + 1) AS EndPosition,
SUBSTRING(@AvailabilityGroups, EndPosition + 1, ISNULL(NULLIF(CHARINDEX(@StringDelimiter, @AvailabilityGroups, EndPosition + 1), 0), LEN(@AvailabilityGroups) + 1) - EndPosition - 1) AS AvailabilityGroupItem
FROM AvailabilityGroups1
WHERE EndPosition < LEN(@AvailabilityGroups) + 1
),
AvailabilityGroups2 (AvailabilityGroupItem, StartPosition, Selected) AS
(
SELECT CASE WHEN AvailabilityGroupItem LIKE '-%' THEN RIGHT(AvailabilityGroupItem,LEN(AvailabilityGroupItem) - 1) ELSE AvailabilityGroupItem END AS AvailabilityGroupItem,
StartPosition,
CASE WHEN AvailabilityGroupItem LIKE '-%' THEN 0 ELSE 1 END AS Selected
FROM AvailabilityGroups1
),
AvailabilityGroups3 (AvailabilityGroupItem, StartPosition, Selected) AS
(
SELECT CASE WHEN AvailabilityGroupItem = 'ALL_AVAILABILITY_GROUPS' THEN '%' ELSE AvailabilityGroupItem END AS AvailabilityGroupItem,
StartPosition,
Selected
FROM AvailabilityGroups2
),
AvailabilityGroups4 (AvailabilityGroupName, StartPosition, Selected) AS
(
SELECT CASE WHEN LEFT(AvailabilityGroupItem,1) = '[' AND RIGHT(AvailabilityGroupItem,1) = ']' THEN PARSENAME(AvailabilityGroupItem,1) ELSE AvailabilityGroupItem END AS AvailabilityGroupItem,
StartPosition,
Selected
FROM AvailabilityGroups3
)
INSERT INTO @SelectedAvailabilityGroups (AvailabilityGroupName, StartPosition, Selected)
SELECT AvailabilityGroupName, StartPosition, Selected
FROM AvailabilityGroups4
OPTION (MAXRECURSION 0)
UPDATE tmpAvailabilityGroups
SET tmpAvailabilityGroups.Selected = SelectedAvailabilityGroups.Selected
FROM @tmpAvailabilityGroups tmpAvailabilityGroups
INNER JOIN @SelectedAvailabilityGroups SelectedAvailabilityGroups
ON tmpAvailabilityGroups.AvailabilityGroupName LIKE REPLACE(SelectedAvailabilityGroups.AvailabilityGroupName,'_','[_]')
WHERE SelectedAvailabilityGroups.Selected = 1
UPDATE tmpAvailabilityGroups