Stored Procedure to Automate Database Restores
It's been awhile since I've posted here, and I've already fallen behind on my New Year's resolution to post once a week. I will do what I can to keep up over the next 51 weeks.
For the past few months, I've been working to standardize the backup processes at my current job. Recently, I've needed to develop a process to restore a read-only copy of a production database using the most recent full backup file and any subsequent log backup files. The procedure below does that. It will work for database backups containing multiple backup files and databases containing multiple data files. However, if you have more than one log file in your database, you are out of luck. See Paul Randal's post Multiple Log Files and Why They're Bad for an excellent explanation of why you shouldn't do that. I will add error handling to deal with this scenario this weekend.
I hope you can put this to use. Let me know if you have questions.
USE YourDatabaseName GO -- ============================================= -- Frank Gill - skreebydba.com -- sp_AutomateDatabaseRestores -- This script is provided with no guarantees -- Please run in you test environment before deploying to production -- The author takes no responsibility if your server descends into a smoking hole -- ============================================= -- Drop stored procedure if it already exists IF EXISTS ( SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE SPECIFIC_SCHEMA = N'dbo' AND SPECIFIC_NAME = N'sp_AutomateDatabaseRestores' ) DROP PROCEDURE dbo.sp_AutomateDatabaseRestores GO CREATE PROCEDURE dbo.sp_AutomateDatabaseRestores @sourcedbname SYSNAME, @restoredbname SYSNAME, @droprestoredb TINYINT = 1, @noexec TINYINT = 0 AS SET NOCOUNT ON --Drop temp tables if they exist IF OBJECT_ID('tempdb..#backupfiles') IS NOT NULL BEGIN DROP TABLE #backupfiles END IF OBJECT_ID('tempdb..#databasefiles') IS NOT NULL BEGIN DROP TABLE #databasefiles END --Create temp tables CREATE TABLE #backupfiles (physicalfilename VARCHAR(2000) ,recoverymodel CHAR(4)) CREATE TABLE #databasefiles (DatabaseName SYSNAME ,LogicalName SYSNAME ,PhysicalName VARCHAR(2000) ,filetype TINYINT) --Declare local variables DECLARE @filecount SMALLINT DECLARE @fullfilecount SMALLINT DECLARE @loopcount SMALLINT DECLARE @datafileloopcount SMALLINT DECLARE @backuploopcount SMALLINT DECLARE @backupfile VARCHAR(2000) DECLARE @sqlstr VARCHAR(MAX) DECLARE @backupfiletype CHAR(4) DECLARE @datafilecount SMALLINT DECLARE @logfilecount SMALLINT DECLARE @logbackupcount SMALLINT DECLARE @datafile VARCHAR(2000) DECLARE @moveparm VARCHAR(2000) DECLARE @fromstatement VARCHAR(2000) DECLARE @logfile SYSNAME DECLARE @physlogfile VARCHAR(2000) DECLARE @physdatafile VARCHAR(2000) --Drop the restored database if it exists and @droprestoredb = 1 IF EXISTS(SELECT 1 FROM sys.databases WHERE name = @restoredbname) AND @droprestoredb = 1 BEGIN SET @sqlstr = 'DROP DATABASE ' + @restoredbname EXEC (@sqlstr) END --Initialize variables SET @moveparm = ' WITH' SET @fromstatement = ' FROM ' SET @loopcount = 1 SET @datafileloopcount = 1 SET @backuploopcount = 1 --Build dynamic SQL to get a list of data and log files for the source database SET @sqlstr = 'INSERT INTO #databasefiles SELECT ' + '''' + @sourcedbname + '''' + ' AS DatabaseName, name, physical_name, type FROM ' + @sourcedbname + '.sys.database_files' --Execute dynamic SQL to return data and log files for the source database EXEC (@sqlstr) --Get counts of data files and log files SELECT @datafilecount = COUNT(*) FROM #databasefiles WHERE filetype = 0 SELECT @logfilecount = COUNT(*) FROM #databasefiles WHERE filetype = 1 --Get the logical and physical log file names SELECT @logfile = LogicalName, @physlogfile = REPLACE(PhysicalName,@sourcedbname,@restoredbname) FROM #databasefiles WHERE filetype = 1 --If the database contains one data file, build the MOVE clause for a single file IF @datafilecount = 1 BEGIN SELECT @datafile = LogicalName, @physdatafile = REPLACE(PhysicalName,@sourcedbname,@restoredbname) FROM #databasefiles WHERE filetype = 0 SET @moveparm = @moveparm + ' MOVE ' + '''' + @datafile + '''' + ' TO ' + '''' + @physdatafile + '''' + ',' + ' MOVE ' + '''' + @logfile + '''' + ' TO ' + '''' + @physlogfile + '''' + ', NORECOVERY' END ELSE --If the database contains more than one data file, loop through the list of files and build a multi-file MOVE statement IF @datafilecount > 1 BEGIN --SELECT @datafileloopcount, @datafilecount WHILE @datafileloopcount <= @datafilecount BEGIN --SELECT TOP (1) LogicalName, REPLACE(PhysicalName,@sourcedbname,@restoredbname) FROM #databasefiles WHERE filetype = 0 SET @physdatafile = (SELECT TOP (1) REPLACE(PhysicalName,@sourcedbname,@restoredbname) FROM #databasefiles WHERE filetype = 0) SET @datafile = (SELECT TOP (1) LogicalName FROM #databasefiles WHERE filetype = 0) SET @moveparm = @moveparm + ' MOVE ' + '''' + @datafile + '''' + ' TO ' + '''' + @physdatafile + '''' + ',' DELETE TOP (1) FROM #databasefiles WHERE filetype = 0 SET @datafileloopcount += 1 END --Append the MOVE command for the log file to the MOVE clause and set it to NORECOVERY SET @moveparm = @moveparm + ' MOVE ' + '''' + @logfile + '''' + ' TO ' + '''' + @physlogfile + '''' + ', NORECOVERY' END IF @droprestoredb = 0 BEGIN SET @moveparm = @moveparm + ', REPLACE' END --Get the most recent full backup file for the source database and insert it into the #backupfiles temp table INSERT INTO #backupfiles SELECT b.physical_device_name, 'FULL' AS [RecoveryModel] from msdb.dbo.backupset a join msdb.dbo.backupmediafamily b on a.media_set_id = b.media_set_id where a.database_name = @sourcedbname AND backup_finish_date = (SELECT MAX(c.backup_finish_date) FROM msdb.dbo.backupset c INNER JOIN msdb.dbo.backupmediafamily d ON c.media_set_id = d.media_set_id WHERE c.database_name = @sourcedbname AND REVERSE(SUBSTRING(REVERSE(d.physical_device_name),1,3)) = 'BAK') order by a.backup_finish_date ASC --Get all log backupfiles run after the latest full backup and insert it into the #backupfiles temp table INSERT INTO #backupfiles SELECT b.physical_device_name, 'LOG' AS [RecoveryModel] from msdb.dbo.backupset a join msdb.dbo.backupmediafamily b on a.media_set_id = b.media_set_id where a.database_name = @sourcedbname AND REVERSE(SUBSTRING(REVERSE(b.physical_device_name),1,3)) = 'TRN' AND backup_finish_date > (SELECT MAX(c.backup_start_date) FROM msdb.dbo.backupset c INNER JOIN msdb.dbo.backupmediafamily d ON c.media_set_id = d.media_set_id WHERE c.database_name = @sourcedbname AND REVERSE(SUBSTRING(REVERSE(d.physical_device_name),1,3)) = 'BAK') order by a.backup_finish_date ASC --Get counts of all backup files, full backup files, and log backup files for use in loop processing below SELECT @filecount = COUNT(*) FROM #backupfiles SELECT @fullfilecount = COUNT(*) FROM #backupfiles WHERE recoverymodel = 'FULL' SELECT @logbackupcount = COUNT(*) FROM #backupfiles WHERE recoverymodel = 'LOG' --While backup files exists, loop through them to generate the restore statement WHILE @loopcount <= @filecount BEGIN --Get the top backup file from the temp table SET @backupfiletype = (SELECT TOP 1 recoverymodel FROM #backupfiles) --If it is a full backup file, build the restore statement IF @backupfiletype = 'FULL' BEGIN --If there are no log backups to apply, replace NORECOVERY with RECOVERY in the MOVE clause IF @logbackupcount = 0 BEGIN SET @moveparm = REPLACE(@moveparm, 'NORECOVERY', 'RECOVERY') END --If there is a single full backup file, build the RESTORE statement with that file IF @fullfilecount = 1 BEGIN SET @backupfile = (SELECT TOP 1 physicalfilename FROM #backupfiles) SET @sqlstr = 'RESTORE DATABASE ' + @restoredbname + ' FROM DISK = ' + '''' + @backupfile + '''' + @moveparm --PRINT @sqlstr DELETE TOP (1) FROM #backupfiles END --If there is more than one full backup file, build the RESTORE command for all full backup files ELSE IF @fullfilecount > 1 BEGIN WHILE @backuploopcount <= @fullfilecount BEGIN SET @backupfile = (SELECT TOP 1 physicalfilename FROM #backupfiles WHERE recoverymodel = 'FULL') SET @fromstatement = @fromstatement + 'DISK = ' + '''' + @backupfile + '''' + ',' DELETE TOP (1) FROM #backupfiles WHERE recoverymodel = 'FULL' SET @backuploopcount += 1 END --Truncate the trailing comma from the FROM clause SET @fromstatement = SUBSTRING(@fromstatement,1,(LEN(@fromstatement) - 1)) SET @sqlstr = 'RESTORE DATABASE ' + @restoredbname + @fromstatement + @moveparm SET @loopcount += 1 --PRINT @sqlstr END END --If it is a log backup file, build a RESTORE log statement --One RESTORE datement will be built for each log backup file ELSE IF @backupfiletype = 'LOG' BEGIN SET @backupfile = (SELECT TOP 1 physicalfilename FROM #backupfiles) SET @sqlstr = 'RESTORE LOG ' + @restoredbname + ' FROM DISK = ' + '''' + @backupfile + '''' --If there is another log backup file, set the RESTORE to WITH NORECOVERY IF (SELECT COUNT(*) FROM #backupfiles) > 1 BEGIN SET @sqlstr = @sqlstr + ' WITH NORECOVERY' END --If there is not another log backup file, set the RESTORE to WITH RECOVERY ELSE BEGIN SET @sqlstr = @sqlstr + ' WITH RECOVERY' END DELETE TOP (1) FROM #backupfiles END --If @noexec = 1, PRINT @sqlstr IF @noexec = 1 BEGIN PRINT @sqlstr END --If @noexec <> 1, EXEC @sqlstr ELSE BEGIN EXEC (@sqlstr) END --Increment the loop count and continue processing backup files SET @loopcount += 1 END GO