-
Notifications
You must be signed in to change notification settings - Fork 41
/
sp_restorescript.sql
644 lines (525 loc) · 28.6 KB
/
sp_restorescript.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
/*
@ ,@
#@@ @@@
@@@@@@@@@;
@@@@@@@@@@
:@@@@@@@@@@
@@@@@@@@@@@
@@@@@@@@@@@;
@@@@@@@@@@@@
@@@@@@@@@@@@
`+@@@@@@@@@@+
.@@` #@,
.@@@@@@@@@@@@@@@@@@@@@@@@:
@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@ @@ @@ #@ @ @
#@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@@@ @@@@ @# #@ @ @
;@@@@@@@@@@@@@@@@@@@@@@@@@@' @ @ @# @# #@ @ #@@@ @@@@ @@@ @@@@@ @@@ @@ @ @ @@ @ @@
.+@@@@@@@@@@@@@@@@+. @@@@ @ @@ @# #@ @ #@ @ @@ @ @ @ @@ @ @ @ `@ @ @ @ @ @@
'` `,# @@@@ @ @@ @# #@ @ #@ @ @# @ @@@@@ @ @ @ @ @ @ @@@@ @`
,@@@@ '@@@@@@@@@@@@@ .@@@@; @ @ @@ @# #@ @ #@ @ @@ @ @@ @ ` @ @ @ @@@ @ @
#@@@@@@ @@@@@ +@@@@ +@@@@@@ @@@@ @@@@ @@@@@ `@@@@@ #@ @ #@ @@ @ @ @ @@ @ @ @ @ @ @ @
@@@@@@@@ ,#. `#; @@@@@@@@' @@ @@ @@@@@ @@, #@ @ @@ @ @@ @@ #@ @@ @ @@ @
;#@@@@@@@@ @@@@@@@@@#, @
,@@@@+ @@@@@+`
.@@` `@@@@ � www.sqlundercover.com
+@@@@ @@@@@+
@@@@@@@ @@@@@@@@#
@@@@@@@ @@@@@@,
:@@@@@' ;@@@@`
`@@@@ @@@+
@#:@@
@@
@`
#
sp_RestoreScript 1.9
Written By David Fowler
29 June 2017
Generate a set of backup commands to restore a database(s) to a specified time
26 July 2017
A bug with the cursor when running on versions of SQL pre-2016 has been fixed
2 January 2018
Broker options included
Restore in standby included
Ability to cope with striped backup files added
10 June 2019
Maximum length of restore statement has been increased to VARCHAR(MAX)
10 July 2019
Wild cards supported in @DatabaseName
Case Sensitive Collations Supported
Fixed bug where not all databases would be set WITH RECOVERY or STANDBY on multi database statements, indstead they were being left with NORECOVERY
12 August 2019
Backup type added to the output
29 August 2019
@Credential parameter added
29 September 2020
@IncludeCopyOnly parameter added
@SingleUser parameter added
File names changed to match db names when WITH MOVE is used
Fix to prevent log backups that were too early from being selected
Fix to add \ at the end of file paths if not already there
Support for DISK, TAPE, LOGICAL DEVICES and Azure blob store backups added
Support for STOPATMARK and STOPBEFOREMARK added
23 November 2020
Fix bug with @SingleUser generating the wrong ALTER statement
16 September 2021
Fix bug where a rogue 0 was being placed after the backup file name
MIT License
------------
Copyright 2018 Sql Undrcover
Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files
(the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge,
publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so,
subject to the following conditions:
The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE
FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION
WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
Parameters
==========
@DatabaseName - A comma delimited list of databases to restore - DEFAULT: Current Database
@RestoreAsName - A comma delimited list of name to restore databases as, the number of should correspond to the number of
databases in @DatabaseName.
@RestoreToDate- See @PointInTime for useage of @RestoreToDate. - DEFAULT: GETDATE()
@FirstLogToRestore- If 'LogsOnly' restore option has been selected, this is the date of the first log to be restored. This
can't be left NULL if 'LogsOnly' has been selected. If any other option has been selected it wil be ignored
@RestoreOptions- 'ToLog' - Script will generate statements including full, differential and log backups - DEFAULT
'ToDiff' Script will only include full and differential backups
'ToFull' Script will only include a full backup
'LogsOnly' - Script will only include log backups between @FirstLogToRestore and @RestoreToDate
'DiffOnly' - Script will include the nearest DIFF to @RestoreToDate
@PointInTime - 1 - Script will restore to a point in time specified in @RestoreToDate
0 - Script will to last backup before the date\time specified in @RestoreToDate - DEFAULT
@WithMoveDataPath - WITH MOVE Path to move data files to. - DEFAULT: original path
@WithMoveLogPath - WITH MOVE Path to move log files to. - DEFAULT:@ original path
@Replace - 1 - Databases will be restored WITH REPLACE
0 - Database won't be restored WITH REPLACE - DEFAULT
@NoRecovery - 1 - Last file will be restored with NORECOVERY, leaving the database in 'restoring' state
0 - Last file will be restored with RECOVERY and the database brought online - DEFAULT
@BrokerOptions - Valid options - ENABLE_BROKER, ERROR_BROKER_CONVERSATIONS, NEW_BROKER
@StandBy - Path for undo file, restores database in standby mode
@Credential - Credential to access Azure blob storage
@IncludeCopyOnly - 1 - Copy only backups are included
0 - Copy only backups are excluded
@SingleUser - Put the database into single user mode before restoring
@StopAtMark - Append stopatmark clause to any log restores
@StopBeforeMark - Append stopbeforemark clause to any log restores
Full documentation and examples can be found at www.sqlundercover.com
*/
USE master
GO
IF OBJECT_ID('dbo.sp_RestoreScript') IS NOT NULL
DROP PROC sp_RestoreScript
GO
CREATE PROC sp_RestoreScript
(
@DatabaseName VARCHAR(3000) = NULL,
@RestoreAsName VARCHAR(3000) = NULL,
@RestoreToDate DATETIME = NULL,
@FirstLogToRestore DATETIME = NULL,
@RestoreOptions VARCHAR(11) = 'ToLog',
@PointInTime BIT = 0,
@WithMoveDataPath VARCHAR(3000) = NULL,
@WithMoveLogPath VARCHAR(3000) = NULL,
@Replace BIT = 0,
@NoRecovery BIT = 0,
@BrokerOptions VARCHAR(30) = '',
@StandBy VARCHAR(260) = NULL,
@RestoreTimeEstimate BIT = 0,
@Credential VARCHAR(128) = NULL,
@IncludeCopyOnly BIT = 1,
@SingleUser BIT = 0,
@StopAtMark VARCHAR(128) = NULL,
@StopBeforeMark VARCHAR(128) = NULL
)
AS
BEGIN
DECLARE @WithMove VARCHAR(3000)
SET NOCOUNT ON
--Check that @RestoreOptions is a valid value
IF @RestoreOptions NOT IN ('ToLog','ToDiff','ToFull','LogsOnly', 'DiffOnly')
RAISERROR (N'Invalid Restore Option specified, please use ToLog, ToDiff, ToFull, DiffOnly or LogsOnly' , 15, 1)
--Check for valid broker options
IF @BrokerOptions NOT IN ('ENABLE_BROKER', 'ERROR_BROKER_CONVERSATIONS', 'NEW_BROKER','')
RAISERROR (N'Invalid Broker Option specified' , 15, 1)
ELSE IF @BrokerOptions != ''
SET @BrokerOptions = ',' + @BrokerOptions
--Check that both 'WithMove' parameters are either both null or both hold a value (why doens't SQL Server give us an XOR?)
IF ((@WithMoveDataPath IS NULL) AND (@WithMoveLogPath IS NOT NULL))
OR
((@WithMoveDataPath IS NOT NULL) AND (@WithMoveLogPath IS NULL))
RAISERROR (N'The ''WithMove'' parameters either both must be NULL or both must hold a value', 15,1)
--set compatibility mode
DECLARE @compatibility BIT
--set compatibility to 1 if server version includes STRING_SPLIT
SELECT @compatibility = CASE
WHEN SERVERPROPERTY ('productversion') >= '13.0.4001.0' AND compatibility_level >= 130 THEN 1
ELSE 0
END
FROM sys.databases
WHERE name = DB_NAME()
--drop temp tables
IF OBJECT_ID('tempdb..#BackupCommands') IS NOT NULL
DROP TABLE #BackupCommands
CREATE TABLE #BackupCommands
(backup_finish_date DATETIME, DBName VARCHAR(255), command VARCHAR(MAX), BackupType VARCHAR(4), AlterCommand BIT)
IF OBJECT_ID('tempdb..#BackupCommandsFinal') IS NOT NULL
DROP TABLE #BackupCommandsFinal
CREATE TABLE #BackupCommandsFinal
(backup_finish_date DATETIME, DBName VARCHAR(255), command VARCHAR(MAX), BackupType VARCHAR(4), AlterCommand BIT)
IF OBJECT_ID('tempdb..#RestoreDatabases') IS NOT NULL
DROP TABLE #RestoreDatabases
CREATE TABLE #RestoreDatabases
(SourceDatabase SYSNAME NOT NULL,
DestinationDatabase SYSNAME NULL)
IF OBJECT_ID('tempdb..#LatestBackups') IS NOT NULL
DROP TABLE #LatestBackups
CREATE TABLE #LatestBackups
(LatestDBName SYSNAME,
backup_finish_date DATETIME)
--remove any spaces in list of databases
SET @DatabaseName = REPLACE(@DatabaseName, ' ','')
SET @RestoreAsName = REPLACE(@RestoreAsName, ' ','')
--@PointInTime can only be true if @RestoreOptions is either 'ToLog' or 'LogsOnly'
IF (@PointInTime = 1) AND (@RestoreOptions NOT IN ('ToLog','LogsOnly'))
BEGIN
RAISERROR (N'Point in time restore is not possible with selected restore options. @PointInTime has been changed to 0', 15,1)
SET @PointInTime = 0
END
--@PointInTime can only be true if @StopAtMark or @StopBeforeMark is false
IF(@PointInTime = 1) AND (@StopAtMark IS NOT NULL OR @StopBeforeMark IS NOT NULL)
RAISERROR (N'@PointInTime cannot be 1 when @StopAtMark or @StopBeforeMark is set', 15,1)
--Both @StopAtMark and @StopBeforeMark can't be set
IF (@StopAtMark IS NOT NULL AND @StopBeforeMark IS NOT NULL)
RAISERROR (N'Only @StopAtMark or @StopBeforeMark can be set, not both', 15,1)
--If @RestoreOptions is 'LogsOnly', a RestoreToDate value must be specified
IF (@RestoreOptions = 'LogsOnly') AND (@FirstLogToRestore IS NULL)
RAISERROR (N'When @RestoreOptions = LogsOnly, a @FirstLogToRestore date must be specified', 15,1)
--Set default value for @RestoreToDate if unspecified
IF (@RestoreToDate IS NULL)
SET @RestoreToDate = GETDATE()
--Set default value for @DatabaseName if unspecified
IF (@DatabaseName IS NULL)
SET @DatabaseName = DB_NAME()
--Declare cursor containing database names
--if compatibility mode = 1 then it's safe to use STRING_SPLIT, otherwise use fn_SplitString
IF (@compatibility = 1)
BEGIN
--raise an error if there's a mismatch in the number of databases in @DatabaseName and @RestoreAsName
IF ((SELECT COUNT(*) FROM STRING_SPLIT(@DatabaseName,','))
!= (SELECT COUNT(*) FROM STRING_SPLIT(@RestoreAsName,',')))
AND @RestoreAsName IS NOT NULL
RAISERROR (N'There is a mismatch in the number of databases in @DatabaseName and @RestoreAsName', 15,1)
--DECLARE DatabaseCur CURSOR STATIC FORWARD_ONLY FOR
INSERT INTO #RestoreDatabases (SourceDatabase,DestinationDatabase)
SELECT SourceDatabase.value AS SourceDatabase,DestinationDatabase.value AS DestinationDatabase
FROM
(SELECT value, ROW_NUMBER() OVER (ORDER BY (SELECT 1)) RowNumber
FROM STRING_SPLIT(@DatabaseName,',') ) SourceDatabase
LEFT JOIN
(SELECT value, ROW_NUMBER() OVER (ORDER BY (SELECT 1)) RowNumber
FROM STRING_SPLIT(@RestoreAsName,',') ) DestinationDatabase
ON SourceDatabase.RowNumber = DestinationDatabase.RowNumber
--check for the existance of wild cards
IF @DatabaseName LIKE '%\%%' ESCAPE '\'
BEGIN
DECLARE @WildCardDB SYSNAME
--wildcards cannot be used with @RestoreAsName
IF (@RestoreAsName IS NOT NULL)
RAISERROR (N'@RestoreAsName must be NULL when wildcards are used in @DatabaseName', 15,1)
--Cursor through wild card databases, selecting from sys.databases
DECLARE WildCardCur CURSOR STATIC FORWARD_ONLY FOR
SELECT SourceDatabase
FROM #RestoreDatabases
WHERE SourceDatabase LIKE '%\%%' ESCAPE '\'
OPEN WildCardCur
FETCH NEXT FROM WildCardCur INTO @WildCardDB
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO #RestoreDatabases(SourceDatabase)
SELECT name
FROM sys.databases
WHERE name LIKE @WildCardDB
FETCH NEXT FROM WildCardCur INTO @WildCardDB
END
--remove wild card entry from #restoredatabases, it's no longer needed
DELETE FROM #RestoreDatabases
WHERE SourceDatabase = @WildCardDB
CLOSE WildCardCur
DEALLOCATE WildCardCur
END
END
ELSE BEGIN
--raise an error if there's a mismatch in the number of databases in @DatabaseName and @RestoreAsName
IF ((SELECT COUNT(*) FROM fn_SplitString(@DatabaseName,','))
!= (SELECT COUNT(*) FROM fn_SplitString(@RestoreAsName,',')))
AND @RestoreAsName IS NOT NULL
RAISERROR (N'There is a mismatch in the number of databases in @DatabaseName and @RestoreAsName', 15,1)
---DECLARE DatabaseCur CURSOR FOR
INSERT INTO #RestoreDatabases (SourceDatabase,DestinationDatabase)
SELECT SourceDatabase.StringElement AS SourceDatabase,DestinationDatabase.StringElement AS DestinationDatabase
FROM
(SELECT StringElement, ROW_NUMBER() OVER (ORDER BY (SELECT 1)) RowNumber
FROM fn_SplitString(@DatabaseName,',') ) SourceDatabase
LEFT JOIN
(SELECT StringElement, ROW_NUMBER() OVER (ORDER BY (SELECT 1)) RowNumber
FROM fn_SplitString(@RestoreAsName,',') ) DestinationDatabase
ON SourceDatabase.RowNumber = DestinationDatabase.RowNumber
--check for the existance of wild cards
IF @DatabaseName LIKE '%\%%' ESCAPE '\'
BEGIN
--wildcards cannot be used with @RestoreAsName
IF (@RestoreAsName IS NOT NULL)
RAISERROR (N'@RestoreAsName must be NULL when wildcards are used in @DatabaseName', 15,1)
--Cursor through wild card databases, selecting from sys.databases
DECLARE WildCardCur CURSOR STATIC FORWARD_ONLY FOR
SELECT SourceDatabase
FROM #RestoreDatabases
WHERE SourceDatabase LIKE '%\%%' ESCAPE '\'
OPEN WildCardCur
FETCH NEXT FROM WildCardCur INTO @WildCardDB
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO #RestoreDatabases(SourceDatabase)
SELECT name
FROM sys.databases
WHERE name LIKE @WildCardDB
FETCH NEXT FROM WildCardCur INTO @WildCardDB
END
--remove wild card entry from #restoredatabases, it's no longer needed
DELETE FROM #RestoreDatabases
WHERE SourceDatabase = @WildCardDB
CLOSE WildCardCur
DEALLOCATE WildCardCur
END
END
DECLARE DatabaseCur CURSOR FOR
SELECT SourceDatabase, DestinationDatabase
FROM #RestoreDatabases
--open cursor
OPEN DatabaseCur
FETCH NEXT FROM DatabaseCur INTO @DatabaseName, @RestoreAsName
WHILE @@FETCH_STATUS = 0
BEGIN
--Insert single user command
IF @SingleUser = 1
BEGIN
INSERT INTO #BackupCommands (DBName, command, AlterCommand)
VALUES (@DatabaseName, 'ALTER DATABASE ' + COALESCE(QUOTENAME(@RestoreAsName), QUOTENAME(@DatabaseName)) + ' SET SINGLE_USER WITH ROLLBACK IMMEDIATE', 1)
END
--Get last full backup for required timeframe
IF (@RestoreOptions IN ('PointInTime','ToLog','ToDiff','ToFull','DiffOnly'))
BEGIN
WITH BackupFilesCTE (physical_device_name, position, StartDateRank, backup_finish_date)
AS
(SELECT CASE WHEN device_type = 2 THEN 'DISK = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 5 THEN 'TAPE = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 9 THEN 'URL = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 102 THEN mediafamily.logical_device_name
ELSE '***UNSUPPORTED DEVICE***'
END,
position,
RANK() OVER (ORDER BY backup_finish_date DESC) AS StartDateRank,
backup_finish_date
FROM msdb.dbo.backupset backupset
INNER JOIN msdb.dbo.backupmediafamily mediafamily ON backupset.media_set_id = mediafamily.media_set_id
WHERE backupset.database_name = @DatabaseName
AND backupset.backup_finish_date < @RestoreToDate
AND backupset.type = 'D'
AND is_copy_only IN (0,@IncludeCopyOnly))
INSERT INTO #BackupCommands (backup_finish_date, DBName, command, BackupType, AlterCommand)
SELECT DISTINCT backup_finish_date, @DatabaseName AS DBName,
'RESTORE DATABASE ' + COALESCE(QUOTENAME(@RestoreAsName), QUOTENAME(@DatabaseName)) + ' FROM ' + STUFF ((SELECT ',' + physical_device_name
FROM BackupFilesCTE
WHERE StartDateRank = 1
FOR XML PATH('')),1,1,'') + ' WITH NORECOVERY, FILE = ' + CAST(position AS VARCHAR) AS Command, 'FULL',0
FROM BackupFilesCTE
WHERE StartDateRank = 1
END
--if Replace is set, add to statement
IF @Replace = 1
BEGIN
UPDATE #BackupCommands
SET command = command + ', REPLACE'
WHERE DBName = @DatabaseName
AND AlterCommand = 0;
END
--if WithMove parameters are set, create WITH MOVE statements
IF (@WithMoveDataPath IS NOT NULL) AND (@WithMoveLogPath IS NOT NULL)
BEGIN
--append \ to the end of path if it's not already
IF (SELECT SUBSTRING(@WithMoveDataPath,LEN(@WithMoveDataPath), 1)) != '\'
SET @WithMoveDataPath = @WithMoveDataPath + '\'
IF (SELECT SUBSTRING(@WithMoveLogPath,LEN(@WithMoveLogPath), 1)) != '\'
SET @WithMoveLogPath = @WithMoveLogPath + '\'
--generate MOVE statement
DECLARE @WithMoveCmd VARCHAR(3000)
SET @WithMoveCmd = ','
SELECT @WithMoveCmd = @WithMoveCmd + STUFF((SELECT ',' + ' MOVE ''' + name + ''' TO ''' +
CASE
WHEN @RestoreAsName IS NULL THEN REPLACE(physical_name,REVERSE(SUBSTRING(REVERSE(physical_name),CHARINDEX('\',REVERSE(physical_name),0), LEN(physical_name))),@WithMoveDataPath) + ''''
ELSE REPLACE(LEFT(physical_name,(LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name),0)+1)),LEFT(physical_name,(LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name),0)+1)),@WithMoveDataPath) /* Base Path */
+REPLACE(RIGHT(physical_name,(CHARINDEX('\',REVERSE(physical_name))-1)),@DatabaseName,@RestoreAsName) + '''' /* append new filename and extension */
END
FROM sys.master_files
WHERE database_id = DB_ID(@DatabaseName)
AND type_desc = 'ROWS'
FOR XML PATH('')) ,1,1,'')
SET @WithMoveCmd = @WithMoveCmd + ','
SELECT @WithMoveCmd = @WithMoveCmd + STUFF((SELECT ',' + 'MOVE ''' + name + ''' TO ''' +
CASE
WHEN @RestoreAsName IS NULL THEN REPLACE(physical_name,REVERSE(SUBSTRING(REVERSE(physical_name),CHARINDEX('\',REVERSE(physical_name),0), LEN(physical_name))),@WithMoveLogPath) + ''''
ELSE REPLACE(LEFT(physical_name,(LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name),0)+1)),LEFT(physical_name,(LEN(physical_name)-CHARINDEX('\',REVERSE(physical_name),0)+1)),@WithMoveLogPath) /* Base Path */
+REPLACE(RIGHT(physical_name,(CHARINDEX('\',REVERSE(physical_name))-1)),@DatabaseName,@RestoreAsName) + '''' /* append new filename and extension */
END
FROM sys.master_files
WHERE database_id = DB_ID(@DatabaseName)
AND type_desc = 'LOG'
FOR XML PATH('')) ,1,1,'')
--append MOVE statement to backup command
UPDATE #BackupCommands
SET command = command + @WithMoveCmd
WHERE DBName = @DatabaseName
AND AlterCommand = 0;
END
--Get last diff for required timeframe
IF (@RestoreOptions IN ('PointInTime','ToLog','ToDiff','DiffOnly'))
BEGIN
WITH BackupFilesCTE (physical_device_name, position, StartDateRank, backup_finish_date)
AS
(SELECT CASE WHEN device_type = 2 THEN 'DISK = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 5 THEN 'TAPE = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 9 THEN 'URL = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 102 THEN mediafamily.logical_device_name
ELSE '***UNSUPPORTED DEVICE***'
END,
position,
RANK() OVER (ORDER BY backup_finish_date DESC) AS StartDateRank,
backup_finish_date
FROM msdb.dbo.backupset backupset
INNER JOIN msdb.dbo.backupmediafamily mediafamily ON backupset.media_set_id = mediafamily.media_set_id
WHERE backupset.database_name = @DatabaseName
AND backupset.backup_finish_date < @RestoreToDate
AND backupset.type = 'I'
AND is_copy_only IN (0,@IncludeCopyOnly))
INSERT INTO #BackupCommands (backup_finish_date, DBName, command, BackupType, AlterCommand)
SELECT DISTINCT backup_finish_date, @DatabaseName AS DBName,
'RESTORE DATABASE ' + COALESCE(QUOTENAME(@RestoreAsName), QUOTENAME(@DatabaseName)) + ' FROM ' + STUFF ((SELECT ',' + physical_device_name
FROM BackupFilesCTE
WHERE StartDateRank = 1
FOR XML PATH('')),1,1,'') + ' WITH NORECOVERY, FILE = ' + CAST(position AS VARCHAR) AS Command, 'DIFF',0
FROM BackupFilesCTE
WHERE StartDateRank = 1
AND backup_finish_date > (SELECT MAX(backup_finish_date) FROM #BackupCommands)
END
--Get all log backups since last full or diff
IF (@RestoreOptions IN ('ToLog','LogsOnly'))
WITH BackupFilesCTE (physical_device_name, position, StartDateRank, backup_finish_date)
AS
(SELECT CASE WHEN device_type = 2 THEN 'DISK = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 5 THEN 'TAPE = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 9 THEN 'URL = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 102 THEN mediafamily.logical_device_name
ELSE '***UNSUPPORTED DEVICE***'
END,
position,
RANK() OVER (ORDER BY backup_finish_date DESC) AS StartDateRank,
backup_finish_date
FROM msdb.dbo.backupset backupset
INNER JOIN msdb.dbo.backupmediafamily mediafamily ON backupset.media_set_id = mediafamily.media_set_id
WHERE backupset.database_name = @DatabaseName
AND backupset.backup_finish_date >
(SELECT COALESCE(MAX(backup_finish_date),@FirstLogToRestore) FROM #BackupCommands)
AND backupset.backup_finish_date < @RestoreToDate
AND backupset.type = 'L'
AND is_copy_only IN (0,@IncludeCopyOnly))
INSERT INTO #BackupCommands (backup_finish_date, DBName, command, BackupType, AlterCommand)
SELECT DISTINCT backup_finish_date, @DatabaseName AS DBName,
'RESTORE LOG ' + COALESCE(QUOTENAME(@RestoreAsName), QUOTENAME(@DatabaseName)) + ' FROM ' +
STUFF ((SELECT DISTINCT ',' + physical_device_name
FROM BackupFilesCTE a
WHERE a.backup_finish_date = b.backup_finish_date
FOR XML PATH('')),1,1,'')
+ ' WITH NORECOVERY, FILE = ' + CAST(position AS VARCHAR)
+ CASE WHEN @StopAtMark IS NOT NULL THEN ', STOPATMARK = ''' + @StopAtMark + ''''
WHEN @StopBeforeMark IS NOT NULL THEN ', STOPBEFOREMARK = ''' + @StopBeforeMark + ''''
ELSE ''
END AS Command, 'LOG',0
FROM BackupFilesCTE b
ORDER BY backup_finish_date ASC
--Get point in time if enabled
IF (@PointInTime = 1) AND (EXISTS (SELECT * FROM #BackupCommands WHERE AlterCommand = 0))
BEGIN
WITH BackupFilesCTE (physical_device_name, position, StartDateRank, backup_finish_date)
AS
(SELECT CASE WHEN device_type = 2 THEN 'DISK = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 5 THEN 'TAPE = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 9 THEN 'URL = ''' + mediafamily.physical_device_name + ''''
WHEN device_type = 102 THEN mediafamily.logical_device_name
ELSE '***UNSUPPORTED DEVICE***'
END,
position,
RANK() OVER (ORDER BY backup_finish_date ASC) AS StartDateRank,
backup_finish_date
FROM msdb.dbo.backupset backupset
INNER JOIN msdb.dbo.backupmediafamily mediafamily ON backupset.media_set_id = mediafamily.media_set_id
WHERE backupset.database_name = @DatabaseName
AND backupset.backup_finish_date > @RestoreToDate
AND backupset.type = 'L'
AND is_copy_only IN (0,@IncludeCopyOnly))
INSERT INTO #BackupCommands (backup_finish_date, DBName, command, BackupType, AlterCommand)
SELECT DISTINCT backup_finish_date, @DatabaseName AS DBName,
'RESTORE DATABASE ' + COALESCE(QUOTENAME(@RestoreAsName), QUOTENAME(@DatabaseName)) + ' FROM ' + STUFF ((SELECT ',' + physical_device_name
FROM BackupFilesCTE
WHERE StartDateRank = 1
FOR XML PATH('')),1,1,'') + ' WITH NORECOVERY, FILE = ' + CAST(position AS VARCHAR) + ', STOPAT = ''' + CAST(@RestoreToDate AS VARCHAR) + '''' AS Command, 'LOG',0
FROM BackupFilesCTE
WHERE StartDateRank = 1
END
INSERT INTO #BackupCommandsFinal (backup_finish_date, DBName, command, BackupType, AlterCommand)
SELECT backup_finish_date, DBName, command, BackupType, AlterCommand FROM #BackupCommands;
TRUNCATE TABLE #BackupCommands
FETCH NEXT FROM DatabaseCur INTO @DatabaseName, @RestoreAsName
END
CLOSE DatabaseCur
DEALLOCATE DatabaseCur
--get list of latest backups for each database
INSERT INTO #LatestBackups(LatestDBName,backup_finish_date)
SELECT DBName, MAX(backup_finish_date)
FROM #BackupCommandsFinal
GROUP BY DBName;
IF @NoRecovery = 0 AND @StandBy IS NULL --if restore with no recovery is off, remove NORECOVERY from the last restore command
BEGIN
UPDATE #BackupCommandsFinal
SET command = REPLACE(command,'NORECOVERY','RECOVERY') + @BrokerOptions
WHERE backup_finish_date = (SELECT backup_finish_date FROM #LatestBackups WHERE DBName = LatestDBName);
END
ELSE IF @StandBy IS NOT NULL
BEGIN
UPDATE #BackupCommandsFinal
SET command = REPLACE(command,'NORECOVERY','STANDBY =''' + @StandBy + '''')
WHERE backup_finish_date = (SELECT backup_finish_date FROM #LatestBackups WHERE DBName = LatestDBName);
END
--if Credential is set, add to statement
IF @Credential IS NOT NULL
BEGIN
UPDATE #BackupCommandsFinal
SET command = command + ', CREDENTIAL = '''+@Credential+''''
WHERE DBName = @DatabaseName
AND AlterCommand = 0;
END
--if DiffOnly, delete full backup file from #BackupCommandsFinal
IF (@RestoreOptions = 'DiffOnly')
BEGIN
DELETE FROM #BackupCommandsFinal
WHERE backup_finish_date =
(SELECT MIN(backup_finish_date)
FROM #BackupCommandsFinal)
END
SELECT backup_finish_date, DBName, command, BackupType
FROM #BackupCommandsFinal
ORDER BY DBName,backup_finish_date
--check for unsupported backup device and raise alert
IF EXISTS (SELECT command FROM #BackupCommandsFinal WHERE command LIKE '%***UNSUPPORTED DEVICE***%')
RAISERROR (N'One or more backups were taken to an unsupported device, possibly by a third party backup tool' , 15, 1)
END