Home > Backup and Recovery > Script for point-in-time recovery

Script for point-in-time recovery

  

This is great script for a point-in-time recovery. Big ‘Thank You’ to Henning Frettem

(and Michael Valentine Jones, SQLTeam.com as, apparently, the original script author)

 

/*
Generate Point-in-time restore script, given only DBName and Point-in-time timestamp
Works only on SQL2008 databases!!

Script for generating restore script for full backup originally created by Michael
Valentine Jones, SQLTeam.com

The rest is created by Henning Frettem, http://www.thefirstsql.com
*/
SET NOCOUNT ON
GO

DECLARE
  
@DBName VARCHAR(200) = ‘MyDB’,
  
@PointInTime DATETIME = ‘2010-08-09 09:10:00’,
  
@Filename VARCHAR(200),
  
@tab VARCHAR(1) = CHAR(9),
  
@cr VARCHAR(2) = CHAR(13)+CHAR(10),
  
@Full_BackupStartDate DATETIME,
  
@Diff_BackupStartDate DATETIME,
  
@Log_BackupStartDate DATETIME,
  
@SQL NVARCHAR(MAX) =

BEGIN TRY
  
–> Performing some checks
  
IF NOT EXISTS (SELECT 1 FROM msdb.dbo.backupset WHERE database_name = @DBName AND TYPE = ‘D’ AND backup_start_date <= @PointInTime)
    
RAISERROR(N’No full backup exists prior to the specified PointInTime’, 16, 1)
  
ELSE IF NOT EXISTS (SELECT 1 FROM msdb.dbo.backupset WHERE database_name = @DBName AND TYPE = ‘L’ AND backup_start_date > @PointInTime)
    
RAISERROR(N’No backup of the log exist after the specified PointInTime’, 16, 1)

  –> Getting the filename and the date of the last full backup prior to the PointInTime
  
SELECT TOP 1
    
@Filename = b.physical_device_name,
    
@Full_BackupStartDate = backup_start_date
  
FROM msdb.dbo.backupset a
    
INNER JOIN msdb.dbo.backupmediafamily b
      
ON a.media_set_id = b.media_set_id
  
WHERE a.database_name = @DBName
    
AND a.TYPE = ‘D’
    
AND a.backup_start_date <= @PointInTime
  
ORDER BY a.backup_start_date DESC

  –> Create temp-tables for file header information
  
DECLARE @header TABLE (
    
BackupName NVARCHAR(128),
    
BackupDescription NVARCHAR(255),
    
BackupType smallint,
    
ExpirationDate DATETIME,
    
Compressed bit,
    
Position smallint,
    
DeviceType tinyint,
    
UserName NVARCHAR(128),
    
ServerName NVARCHAR(128),
    
DatabaseName NVARCHAR(128),
    
DatabaseVersion INT,
    
DatabaseCreationDate DATETIME,
    
BackupSize numeric(20,0),
    
FirstLSN numeric(25,0),
    
LastLSN numeric(25,0),
    
CheckpointLSN numeric(25,0),
    
DatabaseBackupLSN numeric(25,0),
    
BackupStartDate DATETIME,
    
BackupFinishDate DATETIME,
    
SortOrder smallint,
    
CodePage smallint,
    
UnicodeLocaleId INT,
    
UnicodeComparisonStyle INT,
    
CompatibilityLevel tinyint,
    
SoftwareVendorId INT,
    
SoftwareVersionMajor INT,
    
SoftwareVersionMinor INT,
    
SoftwareVersionBuild INT,
    
MachineName NVARCHAR(128),
    
Flags  INT,
    
BindingID UNIQUEIDENTIFIER,
    
RecoveryForkID UNIQUEIDENTIFIER,
    
Collation NVARCHAR(128),
    
FamilyGUID UNIQUEIDENTIFIER,
    
HasBulkLoggedData bit,
    
IsSnapshot bit,
    
IsReadOnly bit,
    
IsSingleUser bit,
    
HasBackupChecksums bit,
    
IsDamaged bit,
    
BeginsLogChain bit,
    
HasIncompleteMetaData bit,
    
IsForceOffline bit,
    
IsCopyOnly bit,
    
FirstRecoveryForkID UNIQUEIDENTIFIER,
    
ForkPointLSN numeric(25,0) NULL,
    
RecoveryModel NVARCHAR(60),
    
DifferentialBaseLSN numeric(25,0) NULL,
    
DifferentialBaseGUID UNIQUEIDENTIFIER,
    
BackupTypeDescription NVARCHAR(60),
    
BackupSetGUID UNIQUEIDENTIFIER NULL,
    
CompressedBackupSize bigint,
    
Seq INT NOT NULL IDENTITY(1,1)
    )

  –> Create temp-table for db file information
  
DECLARE @filelist TABLE  (
    
LogicalName NVARCHAR(128),
    
PhysicalName NVARCHAR(260),
    
TYPE CHAR(1),
    
FileGroupName NVARCHAR(128),
    
Size numeric(20,0),
    
MaxSize numeric(20,0),
    
FileID bigint,
    
CreateLSN numeric(25,0),
    
DropLSN numeric(25,0) NULL,
    
UniqueID UNIQUEIDENTIFIER,
    
ReadOnlyLSN numeric(25,0) NULL,
    
ReadWriteLSN numeric(25,0) NULL,
    
BackupSizeInBytes bigint,
    
SourceBlockSize INT,
    
FileGroupID INT,
    
LogGroupGUID UNIQUEIDENTIFIER NULL,
    
DifferentialBaseLSN numeric(25,0) NULL,
    
DifferentialBaseGUID UNIQUEIDENTIFIER,
    
IsReadOnly bit,
    
IsPresent bit,
    
TDEThummbprint VARBINARY(32),
    
Seq INT NOT NULL IDENTITY(1,1)
    )

  –> Get header and filelist information from the backup file
  
INSERT INTO @header
  
EXEC (‘RESTORE HeaderOnly FROM DISK = ”’ + @Filename + ””)

  INSERT INTO @filelist
  
EXEC (‘RESTORE FilelistOnly FROM DISK = ”’ + @Filename + ””)

  –> Generate the full backup restore script
  
SELECT
    
@SQL = @SQL +
      
CASE
        
WHEN a.Seq = 1 THEN
          
@cr + ‘RESTORE DATABASE [‘ + c.DatabaseName + ‘]’ +
          
@cr + ‘FROM DISK =’ + @cr + @tab + ”” +
          
@Filename + ”” + @cr + ‘WITH’
        
ELSE
      
END
      
+ @cr + @tab + ‘MOVE ”’ + a.LogicalName + ”’ TO ”’ + a.PhysicalName + ”’,’
      
+
      
CASE
        
WHEN a.Seq = b.Seq THEN
          
@cr + @tab + ‘REPLACE, STATS = 5, NORECOVERY’
        
ELSE
      
END
  FROM
    
@filelist a
    
CROSS JOIN
      
(SELECT Seq = MAX(b1.Seq) FROM @filelist b1 ) b
    
CROSS JOIN
      
(SELECT DatabaseName = MAX(c1.DatabaseName) FROM @header c1) c
  
ORDER BY
    
a.Seq

  SELECT @SQL = @SQL + @cr + ‘GO’ + @cr + @cr

  –> Restore the last differential backup if it exists
  
SELECT TOP 1
    
@SQL = @SQL + ‘RESTORE DATABASE [‘ + @DBName + ‘] FROM DISK = ”’ + b.physical_device_name + ”’ WITH NORECOVERY’ + @cr + ‘GO’,
    
@Diff_BackupStartDate = a.backup_start_date
  
FROM msdb.dbo.backupset a
    
INNER JOIN msdb.dbo.backupmediafamily b
      
ON a.media_set_id = b.media_set_id
  
WHERE a.database_name = @DBName
    
AND a.TYPE = ‘I’
    
AND a.backup_start_date > @Full_BackupStartDate
    
AND a.backup_start_date < @PointInTime
  
ORDER BY a.backup_start_date DESC

  IF @Diff_BackupStartDate IS NULL
    
SET @Diff_BackupStartDate = @Full_BackupStartDate

  –> Generate all log restores except the last one
  
SELECT
    
@SQL = @SQL + ‘RESTORE LOG [‘ + @DBName + ‘] FROM DISK = ”’ + b.physical_device_name + ”’ WITH NORECOVERY’ + @cr + ‘GO’ + @cr,
    
@Log_BackupStartDate = a.backup_start_date
  
FROM msdb.dbo.backupset a
    
INNER JOIN msdb.dbo.backupmediafamily b
      
ON a.media_set_id = b.media_set_id
  
WHERE a.database_name = @DBName
    
AND a.TYPE = ‘L’
    
AND a.backup_start_date > @Diff_BackupStartDate
    
AND a.backup_start_date < @PointInTime
  
ORDER BY a.backup_start_date

  –> Generate last log restore script with the stopat command and recovery
  
SELECT TOP 1
    
@SQL = @SQL + ‘RESTORE LOG [‘ + @DBName + ‘] FROM DISK = ”’ + b.physical_device_name + ”’
      WITH RECOVERY, STOPAT = ”’
+ CONVERT(VARCHAR(20), @PointInTime, 120) + ”” + @cr + ‘GO’ + @cr
  
FROM msdb.dbo.backupset a
    
INNER JOIN msdb.dbo.backupmediafamily b
      
ON a.media_set_id = b.media_set_id
  
WHERE a.database_name = @DBName
    
AND a.TYPE = ‘L’
    
AND a.backup_start_date > @PointInTime
  
ORDER BY a.backup_start_date ASC

  PRINT @SQL

END TRY
BEGIN CATCH
  
PRINT ERROR_MESSAGE()
END CATCH

Advertisements
Categories: Backup and Recovery
  1. No comments yet.
  1. No trackbacks yet.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

%d bloggers like this: