Wednesday, September 1, 2010

TSQL - Automate DB restore

This script restores a database without having to know the logical file names. It also lets you place the MDF, LDF and NDF files wherever you want them.  I mainly use it to run a nightly restore on my local machine.  The line with "business logic" does a quick test to see if the database has been changed at all.  There's no need to restore a database if it hasn't been changed, so the "business logic" line is how I tell it to skip the restore step.

/* Automate restore w/o needing to know the logical file names. */

 -- BEGIN - MODIFY THIS CODE - create a blank db
if not exists(select * from master.sys.databases where [name]='DBNAME')
begin
    create database DBNAME
end
go
-- END - MODIFY THIS CODE - create a blank db

declare @strDatabase varchar(130)='DBNAME' -- MODIFY THIS LINE - db name
declare @strBackupFile varchar(500)='e:\docs\db-backups\dbname_backup_file.bak' -- MODIFY THIS LINE - source db backup file
declare @strRestoreMDFFilesTo varchar(500)='e:\docs\sqldata\default\' -- MODIFY THIS LINE - destination restore directory for main files
declare @strRestoreLDFFilesTo varchar(500)='c:\docs\sqldata\default\' -- MODIFY THIS LINE - destination restore directory for tlog files
declare @strRestoreNDFFilesTo varchar(500)='c:\docs\sqldata\default\' -- MODIFY THIS LINE - destination restore directory for non-main files

-- other variables used
declare @strSQL nvarchar(max)
declare @strOriginalPhysicalName varchar(150)
declare @strPhysicalName varchar(150)
declare @strLogicalName varchar(150)
declare @intReturn int

-- begin restoring
begin try
    drop table #tmpFilelist
end try
begin catch
end catch
create table #tmpFilelist (
    LogicalName varchar(64), PhysicalName varchar(130), [Type] varchar(1), FileGroupName varchar(64), Size decimal(20, 0)
    ,MaxSize decimal(25, 0), FileID bigint, CreateLSN decimal(25,0), DropLSN decimal(25,0), UniqueID uniqueidentifier
    ,ReadOnlyLSN decimal(25,0), ReadWriteLSN decimal(25,0), BackSizeInBytes decimal(25,0), SourceBlockSize int
    ,filegroupid int, loggroupguid uniqueidentifier, differentialbaseLSN decimal(25,0), differentialbaseGUID uniqueidentifier
    ,isreadonly bit, ispresent bit, TDEThumbpr decimal
)
if not exists(select * from DBNAME.sys.tables) -- MODIFY THIS LINE - business logic to see if we need to restore the database at all
begin
    print 'Restoring '+@strDatabase+' db ...'
    use master
    exec msdb.dbo.sp_delete_database_backuphistory @database_name = @strDatabase
    use [master]
    exec('alter database '+@strDatabase+' set single_user with rollback immediate')
    use [master]
    exec('drop database '+@strDatabase)
    insert into #tmpFilelist
        exec('restore filelistonly from disk = '''+@strBackupFile+'''')
    set @strSQL='restore database ['+@strDatabase+'] from disk='''+@strBackupFile+''' with '
    set @strSQL=@strSQL+ 'file=1 '
    set @strSQL=@strSQL+ ',nounload '
    set @strSQL=@strSQL+ ',replace '
    set @strSQL=@strSQL+ ',stats=10 '
    while exists(select * from #tmpFilelist)
    begin
        select top 1 @strOriginalPhysicalName=PhysicalName, @strLogicalName=LogicalName from #tmpFilelist
        set @strPhysicalName=@strOriginalPhysicalName
        set @strPhysicalName=reverse(@strPhysicalName)
        set @strPhysicalName=left(@strPhysicalName, charindex('\', @strPhysicalName)-1)
        set @strPhysicalName=reverse(@strPhysicalName)
        set @strPhysicalName=replace(@strPhysicalName, '.', '_'+@strDatabase+'.')
        if @strPhysicalName like '%.mdf'
            set @strPhysicalName=@strRestoreMDFFilesTo+@strPhysicalName
        else if @strPhysicalName like '%.ldf'
            set @strPhysicalName=@strRestoreLDFFilesTo+@strPhysicalName
        else
            set @strPhysicalName=@strRestoreNDFFilesTo+@strPhysicalName
        set @strSQL=@strSQL+ ',move '''+@strLogicalName+''' to '''+@strPhysicalName+''' '
        delete from #tmpFilelist where PhysicalName=@strOriginalPhysicalName
    end
    execute @intReturn=sp_executesql @strSQL
end

No comments: