This script will take a database name and a point in time timestamp as input and generate a script automatically that will include code for doing a full restore including a differential backup and all log backups, up until the given point in time. Please note that it only works for SQL Server 2008 due to the format of the header and the filelist tables. The latest updated version of the script can always be found here: http://thefirstsql.com/2010/08/06/create-a-full-point-in-time-restore-script-automatically//*Generate Point-in-time restore script, given only DBName and Point-in-time timestampWorks only on SQL2008 databases!!Script for generating restore script for full backup originally created by MichaelValentine Jones, SQLTeam.comThe rest is created by Henning Frettem, www.thefirstsql.com*/SET NOCOUNT ONGODECLARE @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, TDEThumbprint 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 @SQLEND TRYBEGIN CATCH PRINT ERROR_MESSAGE()END CATCH
- LumbagoMy blog (yes, I have a blog now! just not that much content yet) -> www.thefirstsql.com