forked from ktaranov/sqlserver-kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
dbo.sp_RestoreGene.sql
1005 lines (842 loc) · 41.4 KB
/
dbo.sp_RestoreGene.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
USE [master]
GO
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_RestoreGene')
EXEC ('CREATE PROC dbo.sp_RestoreGene AS SELECT 1')
GO
/*********************************************************************************************
Restore Generator v4.3 (2014-10-03)
(C) 2012, Paul Brewer
Feedback: [email protected]
Updates: https://paulbrewer.wordpress.com/
This procedure queries msdb database backup history and database file details in master.
It builds and returns RESTORE DATABASE commands as it's result set, it does not execute the commands.
CHANGE LOG:
December 23, 2012 - V1.01 - Release
January 4,2013 - V1.02 - LSN Checks + Bug fix to STOPAT date format
January 11,2013 - V1.03 - SQL Server 2005 compatibility (backup compression problem) & @StandbyMode
January 14, 2013 - V1.04 - WITH COPY and up to 10 striped backup files
January 15, 2013 - V1.05 - Format of constructed restore script, enclose database name in [ ]
February 7, 2013 - V1.06 - Modified WHERE device_type IN (7,102,2)
May 26, 2013 - V1.07 - Various changes for PoSh Driver Script compatibility
October 14, 2013 - V1.08 - Rename parameters, more meaningful names
October 15, 2013 - V2.00 - Add 2nd CTE for striped backup files and remove repeating calls to CTE
November 5, 2013 - V2.01 - Secondary .ndf files only included if @WithMoveDataFiles NOT NULL
- Extended artificial LSN used for sequencing WITH RECOVERY/CHECKDB to 21 characters
- Include database name in results for logging in PoSh
May 23, 2014 - V3.0 - Improved logging and error handling, add 'LogShippingVariableDeclare' parameter
Default is Yes when called from query analysier, set to No when called by PoSh
May 30, 2014 - V3.1 - Restructured CTE, all predicates moved to the CTE
June 6, 2014 - V3.2 - Add 'LogShippingStartTime' parameter for PowerShell script.
To skip subsequent full and diff backups when restoring Logs in PoSh log shipping mode
- Add 'Target Restore Database Name' parameter, Manuj Bahl suggestion
If restoring a specific database, allows overriding restored name
Probably used in conjunction with a @WithMove override of data and log files to a different folder.
- Add LogShippingLastLSN parameter, used to filter results sent to ps_LogShippingLight
June 10, 2014 - V3.3 - Standardize Log Shipping Parameter Names & make &msg variable declare unique
June 27, 2014 - V3.31 - Diff restore bug fix
July 13, 2014 - V3.32 - Feedback from Tony Davis
Rename framework to memorable name 'RestoreGene'
Paramater for WITH REPLACE
August 5, 2014 - V3.4 - Remove TRY CATCH blocks from log restores and checkdb
- Remove CTE's,use #temp tables, suggested by S.Stresser
August 25, 2014 - V3.5 - goestock suggestion - Include device type 7 for AWS EC2 backups
August 29th, 2014 - V3.6 - Richard found and fixed a problem with variable declare where database name has a space or full stop.
July 28, 2015 - V3.7 - Luke Sarro, modifications for case sensitivity & parameter sniffing
August 28, 2015 - V3.8 - Luke Sarro modifications, recovery fork management. supports forking in recovery plans when constructing a restore script.
Only tested where a single fork exists, IE a restore was done to a historic point in time, with recovery, then subsequent log backups are taken.
When a fork exists the restore script will follow the new path for subsequent differential and log backups taken after the forking point.
If no rbackup forks exist, the procedure works as before.
September 02 2015 - V3.9 - SQLMongo modification to replace hyphens in database name
September 04, 2015 - V4.0 - Domingo modification, check for default backup path = ''
September 29, 2015 - V4.2 - Fixes bug identifying full backups taken after a recovery fork, has introduced code duplication to be removed later but fixes problem
October 3, 2015 - V4.3 - Remove code duplication introduced in V4.2
********************************************************************************************/
ALTER PROC dbo.sp_RestoreGene
(
@Database SYSNAME = NULL,
@TargetDatabase SYSNAME = NULL,
@WithMoveDataFiles VARCHAR(2000) = NULL,
@WithMoveLogFile VARCHAR(2000) = NULL,
@FromFileFullUNC VARCHAR(2000) = NULL,
@FromFileDiffUNC VARCHAR(2000) = NULL,
@FromFileLogUNC VARCHAR(2000) = NULL,
@StopAt DATETIME = NULL,
@StandbyMode BIT = 0,
@IncludeSystemDBs BIT = 0,
@WithRecovery BIT = 0,
@WithCHECKDB BIT = 0,
@WithReplace BIT = 0,
@UseDefaultDatabaseBackupPath BIT = 0,
@Log_Reference VARCHAR (250) = NULL,
@LogShippingVariableDeclare BIT = 1,
@LogShippingStartTime DATETIME = NULL,
@LogShippingLastLSN VARCHAR(25) = NULL
)
AS
BEGIN
SET NOCOUNT ON;
-- Avoid Parameter Sniffing Problems
DECLARE @Database_ SYSNAME = @Database,
@TargetDatabase_ SYSNAME = @TargetDatabase,
@WithMoveDataFiles_ VARCHAR(2000) = @WithMoveDataFiles,
@WithMoveLogFile_ VARCHAR(2000) = @WithMoveLogFile,
@FromFileFullUNC_ VARCHAR(2000) = @FromFileFullUNC,
@FromFileDiffUNC_ VARCHAR(2000) = @FromFileDiffUNC,
@FromFileLogUNC_ VARCHAR(2000) = @FromFileLogUNC,
@StopAt_ DATETIME = @StopAt,
@StandbyMode_ BIT = @StandbyMode,
@IncludeSystemDBs_ BIT = @IncludeSystemDBs,
@WithRecovery_ BIT = @WithRecovery,
@WithCHECKDB_ BIT = @WithCHECKDB,
@WithReplace_ BIT = @WithReplace,
@UseDefaultDatabaseBackupPath_ BIT = @UseDefaultDatabaseBackupPath,
@Log_Reference_ VARCHAR (250) = @Log_Reference,
@LogShippingVariableDeclare_ BIT = @LogShippingVariableDeclare,
@LogShippingStartTime_ DATETIME = @LogShippingStartTime,
@LogShippingLastLSN_ VARCHAR(25) = @LogShippingLastLSN
-- Defaults Recovery Point Times
IF ISNULL(@StopAt_,'') = ''
SET @StopAt_ = GETDATE();
IF ISNULL(@LogShippingStartTime_,'') = ''
SET @LogShippingStartTime_ = @StopAt_;
-- Default written to the SQL Server Error Log
IF ISNULL(@Log_Reference_,'') = ''
SET @Log_Reference_ = 'sp_RestoreGene - Recovery in Progress';
-- Allow override of restored database name only if working with a specific database
IF @TargetDatabase_ IS NOT NULL AND @Database_ IS NULL
SET @TargetDatabase_ = NULL;
-- ps_LogShippingLight - Filtered Results
IF ISNULL(@LogShippingLastLSN_,'') = ''
SET @LogShippingLastLSN_ = '-1';
-- Backup file locations defaulted to '' by ps_RestoreGene
IF @FromFileFullUNC_ = ''
SET @FromFileFullUNC_ = NULL;
IF @FromFileDiffUNC_ = ''
SET @FromFileDiffUNC_ = NULL;
IF @FromFileLogUNC_ = ''
SET @FromFileLogUNC_ = NULL;
-- Environment Preparation
IF OBJECT_ID('tempdb..#CTE') IS NOT NULL
DROP TABLE #CTE;
IF OBJECT_ID('tempdb..#Stripes') IS NOT NULL
DROP TABLE #Stripes;
-- Backup forking
IF OBJECT_ID('tempdb..#BackupFork') IS NOT NULL
DROP TABLE #BackupFork;
SELECT rf1.database_name, MAX(database_backup_lsn) database_backup_lsn, MAX(fork_point_lsn) fork_point_lsn, MAX(last_lsn) last_lsn
INTO #BackupFork
FROM msdb.dbo.backupset rf1
INNER JOIN
(
SELECT database_name, MAX(backup_finish_date) AS backup_finish_date
FROM msdb.dbo.backupset
WHERE backup_start_date <= @LogShippingStartTime_
AND fork_point_lsn IS NULL
GROUP BY database_name
) rf2
ON rf1.database_name = rf2.database_name
WHERE fork_point_lsn IS NOT NULL
AND rf1.backup_start_date <= @LogShippingStartTime_
AND rf1.backup_finish_date > rf2.backup_finish_date
GROUP BY rf1.database_name;
CREATE INDEX IDX_BackupFork ON #BackupFork(database_name);
--------------------------------------------------------------
-- CTE1 Full Backup UNION Differential Backup UNION Log Backup
--------------------------------------------------------------
WITH CTE
(
database_name
,current_compatibility_level
,last_lsn
,current_is_read_only
,current_state_desc
,current_recovery_model_desc
,has_backup_checksums
,backup_size
,[type]
,backupmediasetid
,family_sequence_number
,backupstartdate
,physical_device_name
,position
)
AS
(
--------------------------------------------------------------
-- Full backup - Most current immediately before @LogShippingStartTime_
SELECT
bs.database_name
,d.[compatibility_level] AS current_compatibility_level
,bs.last_lsn
,d.[is_read_only] AS current_is_read_only
,d.[state_desc] AS current_state_desc
,d.[recovery_model_desc] current_recovery_model_desc
,bs.has_backup_checksums
,bs.backup_size AS backup_size
,'D' AS [type]
,bs.media_set_id AS backupmediasetid
,mf.family_sequence_number
,x.backup_start_date AS backupstartdate
,mf.physical_device_name
,bs.position
FROM msdb.dbo.backupset bs
INNER JOIN sys.databases d
ON bs.database_name = d.name
INNER JOIN
(
SELECT
a.database_name
,MAX(a.backup_start_date) backup_start_date
FROM msdb.dbo.backupset a
JOIN msdb.dbo.backupmediafamily b
ON a.media_set_id = b.media_set_id
LEFT OUTER JOIN #BackupFork c
ON c.database_name = a.database_name
WHERE a.[type] = 'D'
AND device_type IN (7,102,2)
AND a.is_copy_only = 0
AND a.backup_start_date <= @LogShippingStartTime_
-- Recovery Forking
AND ISNULL(c.fork_point_lsn,a.database_backup_lsn) >= a.database_backup_lsn
AND ((c.fork_point_lsn IS NOT NULL AND a.database_backup_lsn < c.database_backup_lsn) OR c.fork_point_lsn IS NULL)
GROUP BY a.database_name
) x
ON x.database_name = bs.database_name
AND x.backup_start_date = bs.backup_start_date
JOIN msdb.dbo.backupmediafamily mf
ON mf.media_set_id = bs.media_set_id
AND mf.family_sequence_number Between bs.first_family_number And bs.last_family_number
WHERE bs.type = 'D'
AND mf.physical_device_name NOT IN ('Nul', 'Nul:')
UNION
--------------------------------------------------------------
-- Differential backup, most current immediately before @StopAt_
SELECT
bs.database_name
,d.[compatibility_level] AS current_compatibility_level
,bs.last_lsn
,d.[is_read_only] AS current_is_read_only
,d.[state_desc] AS current_state_desc
,d.[recovery_model_desc] current_recovery_model_desc
,bs.has_backup_checksums
,bs.backup_size AS backup_size
,'I' AS [type]
,bs.media_set_id AS backupmediasetid
,mf.family_sequence_number
,x.backup_start_date AS backupstartdate
,mf.physical_device_name
,bs.position
FROM msdb.dbo.backupset bs
INNER JOIN sys.databases d
ON bs.database_name = d.name
INNER JOIN -- Last Full in recovery fork before STOPAT
(
--------------------------------------------
SELECT
a.database_name
,MAX(a.backup_start_date) backup_start_date
FROM msdb.dbo.backupset a
JOIN msdb.dbo.backupmediafamily b
ON a.media_set_id = b.media_set_id
LEFT OUTER JOIN #BackupFork c
ON c.database_name = a.database_name
WHERE a.[type] = 'D'
AND device_type IN (7,102,2)
AND a.is_copy_only = 0
AND a.backup_start_date <= @LogShippingStartTime_
-- Recovery Forking
AND ISNULL(c.fork_point_lsn,a.database_backup_lsn) >= a.database_backup_lsn
AND ((c.fork_point_lsn IS NOT NULL AND a.database_backup_lsn < c.database_backup_lsn) OR c.fork_point_lsn IS NULL)
GROUP BY a.database_name
--------------------------------------------
) y
ON y.database_name = bs.database_name
INNER JOIN -- Last Diff before STOPAT
(
SELECT
a.database_name
,MAX(backup_start_date) backup_start_date
FROM msdb.dbo.backupset a
JOIN msdb.dbo.backupmediafamily b
ON a.media_set_id = b.media_set_id
LEFT OUTER JOIN #BackupFork c
ON c.database_name = a.database_name
WHERE a.[type] = 'I'
AND device_type IN (7,102,2)
AND a.is_copy_only = 0
AND a.backup_start_date <= ISNULL(@StopAt_,GETDATE())
AND a.database_backup_lsn = ISNULL(c.database_backup_lsn,a.database_backup_lsn )
AND a.last_lsn <= ISNULL(c.fork_point_lsn, a.last_lsn)
GROUP BY a.database_name
) x
ON x.database_name = bs.database_name
AND x.backup_start_date = bs.backup_start_date
INNER JOIN msdb.dbo.backupmediafamily mf
ON mf.media_set_id = bs.media_set_id
AND mf.family_sequence_number Between bs.first_family_number And bs.last_family_number
WHERE bs.type = 'I'
AND mf.physical_device_name NOT IN ('Nul', 'Nul:')
AND x.backup_start_date > y.backup_start_date
AND @StopAt_ = @LogShippingStartTime_
UNION
--------------------------------------------------------------
-- Log file backups - after 1st full / before @StopAt_
SELECT
bs.database_name
,d.[compatibility_level] AS current_compatibility_level
,bs.last_lsn
,d.[is_read_only] AS current_is_read_only
,d.[state_desc] AS current_state_desc
,d.[recovery_model_desc] current_recovery_model_desc
,bs.has_backup_checksums
,bs.backup_size AS backup_size
,'L' AS [type]
,bs.media_set_id AS backupmediasetid
,mf.family_sequence_number
,bs.backup_start_date as backupstartdate
,mf.physical_device_name
,bs.position
FROM msdb.dbo.backupset bs
INNER JOIN sys.databases d
ON bs.database_name = d.name
INNER JOIN msdb.dbo.backupmediafamily mf
ON mf.media_set_id = bs.media_set_id
AND mf.family_sequence_number Between bs.first_family_number And bs.last_family_number
INNER JOIN -- After the selected full backup
(
SELECT
a.database_name
,MAX(a.backup_start_date) backup_start_date
FROM msdb.dbo.backupset a
JOIN msdb.dbo.backupmediafamily b
ON a.media_set_id = b.media_set_id
LEFT OUTER JOIN #BackupFork c
ON c.database_name = a.database_name
WHERE a.[type] = 'D'
AND device_type IN (7,102,2)
AND a.is_copy_only = 0
AND a.backup_start_date <= @LogShippingStartTime_
-- Recovery Forking
AND ISNULL(c.fork_point_lsn,a.database_backup_lsn) >= a.database_backup_lsn
AND ((c.fork_point_lsn IS NOT NULL AND a.database_backup_lsn < c.database_backup_lsn) OR c.fork_point_lsn IS NULL)
GROUP BY a.database_name
) y
ON bs.database_name = y.database_name
LEFT OUTER JOIN #BackupFork r
ON r.database_name = bs.database_name
LEFT OUTER JOIN -- Select the first log file after STOPAT
(
SELECT DISTINCT x.database_name, database_backup_lsn,
CASE WHEN y.last_Log_After_StopAt IS NULL THEN CONVERT(datetime, '31 Dec 2050') ELSE y.last_Log_After_StopAt END AS last_Log_After_StopAt
FROM msdb.dbo.backupset x
LEFT JOIN
(
SELECT
database_name
,MIN(backup_start_date) last_Log_After_StopAt
FROM msdb.dbo.backupset a
JOIN msdb.dbo.backupmediafamily b
ON a.media_set_id = b.media_set_id
WHERE a.[type] = 'L'
AND device_type IN (7,102,2)
AND a.backup_start_date > ISNULL(@StopAt_,'1 Jan, 1900')
GROUP BY database_name
) y
ON x.database_name = y.database_name
) x
ON bs.database_name = x.database_name
AND bs.database_backup_lsn = ISNULL(r.database_backup_lsn,bs.database_backup_lsn)
WHERE bs.backup_start_date <= x.last_Log_After_StopAt -- Include 1st log after stop at
AND bs.backup_start_date >= y.backup_start_date -- After last full backup start date
AND bs.database_backup_lsn = ISNULL(r.database_backup_lsn,bs.database_backup_lsn) -- Recovery Fork
AND NOT (bs.first_lsn < ISNULL(r.fork_point_lsn,'99999999999999999') AND bs.last_lsn > ISNULL(r.fork_point_lsn,'00000000000000000') AND bs.last_lsn <> ISNULL(r.last_lsn,bs.last_lsn))
AND mf.physical_device_name NOT IN ('Nul', 'Nul:')
AND bs.type = 'L'
AND device_type IN (7,102,2)
)
SELECT * INTO #CTE FROM CTE;
CREATE INDEX IDX_CTE ON #CTE(database_name);
--------------------------------------------------------------
-- CTE2 Optionally, striped backup file details
--------------------------------------------------------------
WITH Stripes
(
database_name,
backupmediasetid,
family_sequence_number,
last_lsn,
S2_pdn,
S3_pdn,
S4_pdn,
S5_pdn,
S6_pdn,
S7_pdn,
S8_pdn,
S9_pdn,
S10_pdn
)
AS
(
SELECT
Stripe1.database_name,
Stripe1.backupmediasetid,
Stripe1.family_sequence_number,
Stripe1.last_lsn,
Stripe2.physical_device_name AS S2_pdn,
Stripe3.physical_device_name AS S3_pdn,
Stripe4.physical_device_name AS S4_pdn,
Stripe5.physical_device_name AS S5_pdn,
Stripe6.physical_device_name AS S6_pdn,
Stripe7.physical_device_name AS S7_pdn,
Stripe8.physical_device_name AS S8_pdn,
Stripe9.physical_device_name AS S9_pdn,
Stripe10.physical_device_name AS S10_pdn
FROM #CTE AS Stripe1
LEFT OUTER JOIN #CTE AS Stripe2
ON Stripe2.database_name = Stripe1.database_name
AND Stripe2.backupmediasetid = Stripe1.backupmediasetid
AND Stripe2.family_sequence_number = 2
LEFT OUTER JOIN #CTE AS Stripe3
ON Stripe3.database_name = Stripe1.database_name
AND Stripe3.backupmediasetid = Stripe1.backupmediasetid
AND Stripe3.family_sequence_number = 3
LEFT OUTER JOIN #CTE AS Stripe4
ON Stripe4.database_name = Stripe1.database_name
AND Stripe4.backupmediasetid = Stripe1.backupmediasetid
AND Stripe4.family_sequence_number = 4
LEFT OUTER JOIN #CTE AS Stripe5
ON Stripe5.database_name = Stripe1.database_name
AND Stripe5.backupmediasetid = Stripe1.backupmediasetid
AND Stripe5.family_sequence_number = 5
LEFT OUTER JOIN #CTE AS Stripe6
ON Stripe6.database_name = Stripe1.database_name
AND Stripe6.backupmediasetid = Stripe1.backupmediasetid
AND Stripe6.family_sequence_number = 6
LEFT OUTER JOIN #CTE AS Stripe7
ON Stripe7.database_name = Stripe1.database_name
AND Stripe7.backupmediasetid = Stripe1.backupmediasetid
AND Stripe7.family_sequence_number = 7
LEFT OUTER JOIN #CTE AS Stripe8
ON Stripe8.database_name = Stripe1.database_name
AND Stripe8.backupmediasetid = Stripe1.backupmediasetid
AND Stripe8.family_sequence_number = 8
LEFT OUTER JOIN #CTE AS Stripe9
ON Stripe9.database_name = Stripe1.database_name
AND Stripe9.backupmediasetid = Stripe1.backupmediasetid
AND Stripe9.family_sequence_number = 9
LEFT OUTER JOIN #CTE AS Stripe10
ON Stripe10.database_name = Stripe1.database_name
AND Stripe10.backupmediasetid = Stripe1.backupmediasetid
AND Stripe10.family_sequence_number = 10
)
SELECT * INTO #Stripes FROM Stripes;
CREATE INDEX IDX_Stripes ON #Stripes(database_name);
--------------------------------------------------------------
-- Results, T-SQL RESTORE commands, below are based on CTE's above
--------------------------------------------------------------
SELECT
a.Command AS TSQL,
CONVERT(nvarchar(30), a.backupstartdate, 126)
AS BackupDate,
a.BackupDevice,
a.last_lsn,
a.database_name ,
--ROW_NUMBER() OVER(ORDER BY database_name, Sequence, last_lsn) AS SortSequence
ROW_NUMBER() OVER(ORDER BY database_name, Sequence, a.backupstartdate) AS SortSequence
FROM
(
--------------------------------------------------------------
-- Most recent full backup
--------------------------------------------------------------
SELECT
';RESTORE DATABASE [' + CASE ISNULL(@TargetDatabase_,'') WHEN '' THEN d.[name] ELSE @TargetDatabase_ END + ']' + SPACE(1) +
'FROM DISK = N' + '''' +
CASE ISNULL(@FromFileFullUNC_,'Actual')
WHEN 'Actual' THEN #CTE.physical_device_name
ELSE @FromFileFullUNC_ + SUBSTRING(#CTE.physical_device_name,LEN(#CTE.physical_device_name) - CHARINDEX('\',REVERSE(#CTE.physical_device_name),1) + 2,CHARINDEX('\',REVERSE(#CTE.physical_device_name),1) + 1)
END + '''' + SPACE(1) +
-- Striped backup files
CASE ISNULL(#Stripes.S2_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S2_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S2_pdn,LEN(#Stripes.S2_pdn) - CHARINDEX('\',REVERSE(#Stripes.S2_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S2_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S3_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S3_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S3_pdn,LEN(#Stripes.S3_pdn) - CHARINDEX('\',REVERSE(#Stripes.S3_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S3_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S4_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S4_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S4_pdn,LEN(#Stripes.S4_pdn) - CHARINDEX('\',REVERSE(#Stripes.S4_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S4_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S5_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S5_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S5_pdn,LEN(#Stripes.S5_pdn) - CHARINDEX('\',REVERSE(#Stripes.S5_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S5_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S6_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S6_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S6_pdn,LEN(#Stripes.S6_pdn) - CHARINDEX('\',REVERSE(#Stripes.S6_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S6_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S7_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S7_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S7_pdn,LEN(#Stripes.S7_pdn) - CHARINDEX('\',REVERSE(#Stripes.S7_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S7_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S8_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S8_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S8_pdn,LEN(#Stripes.S8_pdn) - CHARINDEX('\',REVERSE(#Stripes.S8_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S8_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S9_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S9_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S9_pdn,LEN(#Stripes.S9_pdn) - CHARINDEX('\',REVERSE(#Stripes.S9_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S9_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S10_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileFullUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S10_pdn ELSE @FromFileFullUNC_ + SUBSTRING(#Stripes.S10_pdn,LEN(#Stripes.S10_pdn) - CHARINDEX('\',REVERSE(#Stripes.S10_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S10_pdn),1) + 1) END + ''''
END +
' WITH ' + CASE ISNULL(@WithReplace_,0) WHEN 1 THEN 'REPLACE, ' ELSE '' END + 'FILE = ' + CAST(#CTE.position AS VARCHAR(5)) + ',' +
CASE #CTE.has_backup_checksums WHEN 1 THEN 'CHECKSUM, ' ELSE ' ' END +
CASE @StandbyMode_ WHEN 0 THEN 'NORECOVERY,' ELSE 'STANDBY =N' + '''' + ISNULL(@FromFileFullUNC_,SUBSTRING(#CTE.physical_device_name,1,LEN(#CTE.physical_device_name) - CHARINDEX('\',REVERSE(#CTE.physical_device_name)))) + '\' + d.name + '_ROLLBACK_UNDO.bak ' + '''' + ',' END + SPACE(1) +
'STATS=10,' + SPACE(1) +
'MOVE N' + '''' + x.LogicalName + '''' + ' TO ' +
'''' +
CASE ISNULL(@WithMoveDataFiles_,'Actual')
WHEN 'Actual' THEN x.PhysicalName
ELSE @WithMoveDataFiles_ + SUBSTRING(x.PhysicalName,LEN(x.PhysicalName) - CHARINDEX('\',REVERSE(x.PhysicalName),1) + 2,CHARINDEX('\',REVERSE(x.PhysicalName),1) + 1)
END + '''' + ',' + SPACE(1) +
'MOVE N' + '''' + y.LogicalName + '''' + ' TO ' +
'''' +
CASE ISNULL(@WithMoveLogFile_ ,'Actual')
WHEN 'Actual' THEN y.PhysicalName
ELSE @WithMoveLogFile_ + SUBSTRING(y.PhysicalName,LEN(y.PhysicalName) - CHARINDEX('\',REVERSE(y.PhysicalName),1) + 2,CHARINDEX('\',REVERSE(y.PhysicalName),1) + 1)
END + '''' AS Command,
1 AS Sequence,
d.name AS database_name,
#CTE.physical_device_name AS BackupDevice,
#CTE.backupstartdate,
#CTE.backup_size,
#CTE.last_lsn
FROM sys.databases d
JOIN
(
SELECT
DB_NAME(mf.database_id) AS name
,mf.Physical_Name AS PhysicalName
,mf.Name AS LogicalName
FROM sys.master_files mf
WHERE type_desc = 'ROWS'
AND mf.file_id = 1
) x
ON d.name = x.name
JOIN
(
SELECT
DB_NAME(mf.database_id) AS name, type_desc
,mf.Physical_Name PhysicalName
,mf.Name AS LogicalName
FROM sys.master_files mf
WHERE type_desc = 'LOG'
) y
ON d.name = y.name
LEFT OUTER JOIN #CTE
ON #CTE.database_name = d.name
AND #CTE.family_sequence_number = 1
JOIN #Stripes
ON #Stripes.database_name = d.name
AND #Stripes.backupmediasetid = #CTE.backupmediasetid
AND #Stripes.last_lsn = #CTE.last_lsn
WHERE #CTE.[type] = 'D'
AND #CTE.family_sequence_number = 1
--------------------------------------------------------------
-- Most recent differential backup
--------------------------------------------------------------
UNION
SELECT
';RESTORE DATABASE [' + CASE ISNULL(@TargetDatabase_,'') WHEN '' THEN d.[name] ELSE @TargetDatabase_ END + ']' + SPACE(1) +
'FROM DISK = N' + '''' +
CASE ISNULL(@FromFileDiffUNC_,'Actual')
WHEN 'Actual' THEN #CTE.physical_device_name
ELSE @FromFileDiffUNC_ + SUBSTRING(#CTE.physical_device_name,LEN(#CTE.physical_device_name) - CHARINDEX('\',REVERSE(#CTE.physical_device_name),1) + 2,CHARINDEX('\',REVERSE(#CTE.physical_device_name),1) + 1)
END + '''' + SPACE(1) +
-- Striped backup files
CASE ISNULL(#Stripes.S2_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S2_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S2_pdn,LEN(#Stripes.S2_pdn) - CHARINDEX('\',REVERSE(#Stripes.S2_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S2_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S3_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S3_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S3_pdn,LEN(#Stripes.S3_pdn) - CHARINDEX('\',REVERSE(#Stripes.S3_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S3_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S4_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S4_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S4_pdn,LEN(#Stripes.S4_pdn) - CHARINDEX('\',REVERSE(#Stripes.S4_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S4_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S5_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S5_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S5_pdn,LEN(#Stripes.S5_pdn) - CHARINDEX('\',REVERSE(#Stripes.S5_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S5_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S6_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S6_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S6_pdn,LEN(#Stripes.S6_pdn) - CHARINDEX('\',REVERSE(#Stripes.S6_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S6_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S7_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S7_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S7_pdn,LEN(#Stripes.S7_pdn) - CHARINDEX('\',REVERSE(#Stripes.S7_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S7_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S8_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S8_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S8_pdn,LEN(#Stripes.S8_pdn) - CHARINDEX('\',REVERSE(#Stripes.S8_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S8_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S9_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S9_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S9_pdn,LEN(#Stripes.S9_pdn) - CHARINDEX('\',REVERSE(#Stripes.S9_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S9_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S10_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileDiffUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S10_pdn ELSE @FromFileDiffUNC_ + SUBSTRING(#Stripes.S10_pdn,LEN(#Stripes.S10_pdn) - CHARINDEX('\',REVERSE(#Stripes.S10_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S10_pdn),1) + 1) END + ''''
END +
' WITH FILE = ' + CAST(#CTE.position AS VARCHAR(5)) + ',' +
CASE #CTE.has_backup_checksums WHEN 1 THEN 'CHECKSUM, ' ELSE ' ' END +
CASE @StandbyMode_ WHEN 0 THEN 'NORECOVERY,' ELSE 'STANDBY =N' + '''' + ISNULL(@FromFileFullUNC_,SUBSTRING(#CTE.physical_device_name,1,LEN(#CTE.physical_device_name) - CHARINDEX('\',REVERSE(#CTE.physical_device_name)))) + '\' + d.name + '_ROLLBACK_UNDO.bak ' + '''' + ',' END + SPACE(1) +
'STATS=10,' + SPACE(1) +
'MOVE N' + '''' + x.LogicalName + '''' + ' TO ' +
'''' +
CASE ISNULL(@WithMoveDataFiles_,'Actual')
WHEN 'Actual' THEN x.PhysicalName
ELSE @WithMoveDataFiles_ + SUBSTRING(x.PhysicalName,LEN(x.PhysicalName) - CHARINDEX('\',REVERSE(x.PhysicalName),1) + 2,CHARINDEX('\',REVERSE(x.PhysicalName),1) + 1)
END + '''' + ',' + SPACE(1) +
'MOVE N' + '''' + y.LogicalName + '''' + ' TO ' +
'''' +
CASE ISNULL(@WithMoveLogFile_ ,'Actual')
WHEN 'Actual' THEN y.PhysicalName
ELSE @WithMoveLogFile_ + SUBSTRING(y.PhysicalName,LEN(y.PhysicalName) - CHARINDEX('\',REVERSE(y.PhysicalName),1) + 2,CHARINDEX('\',REVERSE(y.PhysicalName),1) + 1)
END + '''' AS Command,
32769/2 AS Sequence,
d.name AS database_name,
#CTE.physical_device_name AS BackupDevice,
#CTE.backupstartdate,
#CTE.backup_size,
#CTE.last_lsn
FROM sys.databases d
JOIN #CTE
ON #CTE.database_name = d.name
AND #CTE.family_sequence_number = 1
LEFT OUTER JOIN #Stripes
ON #Stripes.database_name = d.name
AND #Stripes.backupmediasetid = #CTE.backupmediasetid
AND #Stripes.last_lsn = #CTE.last_lsn
INNER JOIN
(
SELECT
DB_NAME(mf.database_id) AS name
,mf.Physical_Name AS PhysicalName
,mf.Name AS LogicalName
FROM sys.master_files mf
WHERE type_desc = 'ROWS'
AND mf.file_id = 1
) x
ON d.name = x.name
JOIN
(
SELECT
DB_NAME(mf.database_id) AS name, type_desc
,mf.Physical_Name PhysicalName
,mf.Name AS LogicalName
FROM sys.master_files mf
WHERE type_desc = 'LOG'
) y
ON d.name = y.name
WHERE #CTE.[type] = 'I'
AND #CTE.family_sequence_number = 1
--------------------------------------------------------------
UNION -- Log backups taken since most recent full or diff
--------------------------------------------------------------
SELECT
';BEGIN TRY RESTORE LOG [' + CASE ISNULL(@TargetDatabase_,'') WHEN '' THEN d.[name] ELSE @TargetDatabase_ END + ']' + SPACE(1) +
'FROM DISK = N' + '''' + --#CTE.physical_device_name + '''' + SPACE(1) +
CASE ISNULL(@FromFileLogUNC_,'Actual')
WHEN 'Actual' THEN #CTE.physical_device_name
ELSE @FromFileLogUNC_ + SUBSTRING(#CTE.physical_device_name,LEN(#CTE.physical_device_name) - CHARINDEX('\',REVERSE(#CTE.physical_device_name),1) + 2,CHARINDEX('\',REVERSE(#CTE.physical_device_name),1) + 1)
END + '''' +
-- Striped backup files
CASE ISNULL(#Stripes.S2_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S2_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S2_pdn,LEN(#Stripes.S2_pdn) - CHARINDEX('\',REVERSE(#Stripes.S2_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S2_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S3_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S3_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S3_pdn,LEN(#Stripes.S3_pdn) - CHARINDEX('\',REVERSE(#Stripes.S3_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S3_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S4_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S4_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S4_pdn,LEN(#Stripes.S4_pdn) - CHARINDEX('\',REVERSE(#Stripes.S4_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S4_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S5_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S5_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S5_pdn,LEN(#Stripes.S5_pdn) - CHARINDEX('\',REVERSE(#Stripes.S5_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S5_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S6_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S6_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S6_pdn,LEN(#Stripes.S6_pdn) - CHARINDEX('\',REVERSE(#Stripes.S6_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S6_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S7_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S7_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S7_pdn,LEN(#Stripes.S7_pdn) - CHARINDEX('\',REVERSE(#Stripes.S7_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S7_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S8_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S8_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S8_pdn,LEN(#Stripes.S8_pdn) - CHARINDEX('\',REVERSE(#Stripes.S8_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S8_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S9_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S9_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S9_pdn,LEN(#Stripes.S9_pdn) - CHARINDEX('\',REVERSE(#Stripes.S9_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S9_pdn),1) + 1) END + ''''
END +
CASE ISNULL(#Stripes.S10_pdn,'')
WHEN '' THEN ''
ELSE ', DISK = N' + '''' + CASE ISNULL(@FromFileLogUNC_,'Actual') WHEN 'Actual' THEN #Stripes.S10_pdn ELSE @FromFileLogUNC_ + SUBSTRING(#Stripes.S10_pdn,LEN(#Stripes.S10_pdn) - CHARINDEX('\',REVERSE(#Stripes.S10_pdn),1) + 2,CHARINDEX('\',REVERSE(#Stripes.S10_pdn),1) + 1) END + ''''
END +
CASE @StandbyMode_ WHEN 0 THEN ' WITH NORECOVERY,' ELSE ' WITH STANDBY =N' + '''' + ISNULL(@FromFileFullUNC_,SUBSTRING(#CTE.physical_device_name,1,LEN(#CTE.physical_device_name) - CHARINDEX('\',REVERSE(#CTE.physical_device_name)))) + '\' + d.name + '_ROLLBACK_UNDO.bak ' + '''' + ',' END + SPACE(1) +
CASE #CTE.has_backup_checksums WHEN 1 THEN ' CHECKSUM, ' ELSE ' ' END +
+ 'FILE = ' + CAST(#CTE.position AS VARCHAR(5)) +
' ,STOPAT = ' + '''' + CONVERT(VARCHAR(21),@StopAt_,120) + '''' +
' ,MOVE N' + '''' + x2.LogicalName + '''' + ' TO ' +
'''' +
CASE ISNULL(@WithMoveDataFiles_,'Actual')
WHEN 'Actual' THEN x2.PhysicalName
ELSE @WithMoveDataFiles_ + SUBSTRING(x2.PhysicalName,LEN(x2.PhysicalName) - CHARINDEX('\',REVERSE(x2.PhysicalName),1) + 2,CHARINDEX('\',REVERSE(x2.PhysicalName),1) + 1)
END + '''' + ',' + SPACE(1) +
' MOVE N' + '''' + y1.LogicalName + '''' + ' TO ' +
'''' +
CASE ISNULL(@WithMoveLogFile_ ,'Actual')
WHEN 'Actual' THEN y1.PhysicalName
ELSE @WithMoveLogFile_ + SUBSTRING(y1.PhysicalName,LEN(y1.PhysicalName) - CHARINDEX('\',REVERSE(y1.PhysicalName),1) + 2,CHARINDEX('\',REVERSE(y1.PhysicalName),1) + 1)
END + '''' + 'END TRY BEGIN CATCH PRINT ' + '''' + 'Transaction Log File Restore Exclusion - Check Recovery Sequence.' + '''' + ' END CATCH;' AS Command,
32769 AS Sequence,
d.name AS database_name,
#CTE.physical_device_name AS BackupDevice,
#CTE.backupstartdate,
#CTE.backup_size,
#CTE.last_lsn
FROM sys.databases d
INNER JOIN
(
SELECT
DB_NAME(mf.database_id) AS name
,mf.Physical_Name AS PhysicalName
,mf.Name AS LogicalName
FROM sys.master_files mf
WHERE type_desc = 'ROWS'
AND mf.file_id = 1
) x2
ON d.name = x2.name
INNER JOIN
(
SELECT
DB_NAME(mf.database_id) AS name, type_desc
,mf.Physical_Name PhysicalName
,mf.Name AS LogicalName
FROM sys.master_files mf
WHERE type_desc = 'LOG'
) y1
ON d.name = y1.name
INNER JOIN #CTE
ON #CTE.database_name = d.name
AND #CTE.family_sequence_number = 1
LEFT OUTER JOIN #Stripes
ON #Stripes.database_name = d.name
AND #Stripes.backupmediasetid = #CTE.backupmediasetid
AND #Stripes.last_lsn = #CTE.last_lsn
LEFT OUTER JOIN
(
SELECT database_name, MAX(last_lsn) last_lsn
FROM #CTE
WHERE [type] = 'I'
GROUP BY database_name
) after_diff
ON after_diff.database_name = #CTE.database_name
WHERE #CTE.[type] = 'L'
AND #CTE.family_sequence_number = 1
AND #CTE.last_lsn > ISNULL(after_diff.last_lsn,'0')
--------------------------------------------------------------
UNION -- Declare @msg_ variable
--------------------------------------------------------------
SELECT
-- '; DECLARE @msg_' + d.name + ' VARCHAR(1000)' AS Command,
';DECLARE @msg_' + REPLACE(REPLACE(REPLACE(d.name,' ','_'),'.','_'),'-','_') + ' VARCHAR(1000)' AS Command,
0 AS Sequence,
d.name AS database_name,
'' AS BackupDevice,
GETDATE() AS backupstartdate,
#CTE.backup_size,
'0' AS last_lsn
FROM sys.databases d
JOIN #CTE
ON #CTE.database_name = d.name
WHERE #CTE.[type] = 'D'
AND @LogShippingVariableDeclare_ = 1
--------------------------------------------------------------
UNION -- Restore WITH RECOVERY
--------------------------------------------------------------
SELECT
';SET @msg_' + REPLACE(REPLACE(REPLACE(d.name,' ','_'),'.','_'),'-','_') + ' = ' + '''' + @Log_Reference_ + '''' + '; RAISERROR (@msg_' + REPLACE(REPLACE(REPLACE(d.name,' ','_'),'.','_'),'-','_') + ',0,0) WITH LOG' + ';RESTORE DATABASE [' + CASE ISNULL(@TargetDatabase_,'') WHEN '' THEN d.[name] ELSE @TargetDatabase_ END + ']' + SPACE(1) + 'WITH RECOVERY' AS Command,
32771 AS Sequence,
d.name AS database_name,
'' AS BackupDevice,
GETDATE() AS backupstartdate,
#CTE.backup_size,
'999999999999999999998' AS last_lsn
FROM sys.databases d
JOIN #CTE
ON #CTE.database_name = d.name
WHERE #CTE.[type] = 'D'
AND @WithRecovery_ = 1
--------------------------------------------------------------
UNION -- CHECKDB
--------------------------------------------------------------
SELECT
';SET @msg_' + REPLACE(REPLACE(REPLACE(d.name,' ','_'),'.','_'),'-','_') + ' = ' + '''' + @Log_Reference_ + '''' + '; RAISERROR (@msg_' + REPLACE(REPLACE(REPLACE(d.name,' ','_'),'.','_'),'-','_') + ',0,0) WITH LOG' + ';DBCC CHECKDB(' + '''' + CASE ISNULL(@TargetDatabase_,'') WHEN '' THEN d.[name] ELSE @TargetDatabase_ END + '''' + ') WITH NO_INFOMSGS, ALL_ERRORMSGS' AS Command,
32772 AS Sequence,
d.name AS database_name,
'' AS BackupDevice,
DATEADD(minute,1,GETDATE()) AS backupstartdate,
#CTE.backup_size,
'999999999999999999999' AS last_lsn
FROM sys.databases d
JOIN #CTE
ON #CTE.database_name = d.name
WHERE #CTE.[type] = 'D'
AND @WithCHECKDB_ = 1
AND @WithRecovery_ = 1
--------------------------------------------------------------
UNION -- WITH MOVE secondary data files, allows for up to 32769/2 file groups
--------------------------------------------------------------
SELECT
', MOVE N' + '''' + b.name + '''' + ' TO N' + '''' +
CASE ISNULL(@WithMoveDataFiles_,'Actual')
WHEN 'Actual' THEN b.physical_name
ELSE @WithMoveDataFiles_ + SUBSTRING(b.Physical_Name,LEN(b.Physical_Name) - CHARINDEX('\',REVERSE(b.Physical_Name),1) + 2,CHARINDEX('\',REVERSE(b.Physical_Name),1) + 1)
END + '''',
b.file_id AS Sequence,
DB_NAME(b.database_id) AS database_name,
'SECONDARY FULL' AS BackupDevice,
#CTE.backupstartdate,
#CTE.backup_size,
#CTE.last_lsn
FROM sys.master_files b
INNER JOIN #CTE
ON #CTE.database_name = DB_NAME(b.database_id)
WHERE #CTE.[type] = 'D'
AND b.type_desc = 'ROWS'
AND b.file_id > 2
AND @WithMoveDataFiles_ IS NOT NULL
--------------------------------------------------------------
) a
--------------------------------------------------------------
WHERE a.database_name = ISNULL(@Database_,a.database_name)
AND (@IncludeSystemDBs_ = 1 OR a.database_name NOT IN('master','model','msdb'))
AND a.last_lsn > @LogShippingLastLSN_
ORDER BY
database_name,
Sequence,