Problem
When a failure occurs you need to act quickly to possibly restore your database. When you are performing both full and transaction log backups there are multiple files that will need to be restored and therefore your restore script could get quite long and tedious to write. When using Enterprise Manager or SQL Server Management Studio the GUI gives you the list of files that should be restored, but what if you need to do this manually or you would rather have a script to perform the restore process instead of using the GUI. How can you easily generate the restore script?
Solution
For every backup that occurs in SQL Server an entry is made into the system tables that reside in the MSDB database. This includes both native SQL Server backups as well as backups that occur using third party tools. These tables that hold this backup information are:
- backupfile -- contains one row for each data file or log file backed up
- backupmediafamily -- contains one row for each media family
- backupmediaset -- contains one row for each backup media set
- backupset -- contains one row for each backup set
The following is a simple script that queries the backupset and backupmediafamily tables. This script assumes that the backup files are being written to disk and not directly to tape, but this script can be modified to include these checks as well. The idea behind this is that you will want to always restore your latest backup set, which is probably the set of files you still have on disk. In most cases when a failure occurs or someone accidentally deleted important data you will probably only need to go back to the latest full backup and the appropriate transaction logs.
Here is the script, the only parameter that needs to be set is the database that you want to retrieve backup information for. The process will then find the latest Full backup and all transaction log backups that have occurred after this full backup. The last step is to create a WITH RECOVERY command that puts the database online and makes it accesible.
DECLARE @databaseName sysname DECLARE @backupStartDate datetime DECLARE @backup_set_id_start INT DECLARE @backup_set_id_end INT -- set database to be used SET @databaseName = 'enterDatabaseNameHere' SELECT @backup_set_id_start = MAX ( backup_set_id ) FROM msdb.dbo.backupset WHERE database_name = @databaseName AND type = 'D' SELECT @backup_set_id_end = MIN ( backup_set_id ) FROM msdb.dbo.backupset WHERE database_name = @databaseName AND type = 'D' AND backup_set_id > @backup_set_id_start IF @backup_set_id_end IS NULL SET @backup_set_id_end = 999999999 SELECT backup_set_id , 'RESTORE DATABASE ' + @databaseName + ' FROM DISK = ''' + mf.physical_device_name + ''' WITH NORECOVERY' FROM msdb.dbo.backupset b , msdb.dbo.backupmediafamily mf WHERE b.media_set_id = mf.media_set_id AND b.database_name = @databaseName AND b.backup_set_id = @backup_set_id_start UNION SELECT backup_set_id , 'RESTORE LOG ' + @databaseName + ' FROM DISK = ''' + mf.physical_device_name + ''' WITH NORECOVERY' FROM msdb.dbo.backupset b , msdb.dbo.backupmediafamily mf WHERE b.media_set_id = mf.media_set_id AND b.database_name = @databaseName AND b.backup_set_id >= @backup_set_id_start AND b.backup_set_id < @backup_set_id_end AND b.type = 'L' UNION SELECT 999999999 AS backup_set_id , 'RESTORE DATABASE ' + @databaseName + ' WITH RECOVERY' ORDER BY backup_set_id |
Line 1 is the full backup, lines 2 and 3 are the transaction log backups and line 4 is the WITH RECOVERY option which takes the database out of the loading state and makes the database accessible.
Summary
This is a very basic process of finding the latest full backup and all of the transaction log backups. It does not take into consideration additional backups that are written to the same file or differential backups. There are several tweaks that could be made to further enhance this script, but hopefully this gives you a starting point to automate your restore scripts instead of having to rely on the GUI to provide this data or having to manually type each command for every single backup.
No comments:
Post a Comment