Very often, myself or my friends were in need of a script to restore the backups from a predefined folder. It was hard to write the script in the hour of need. Hence, I thought I will share the script that has been created recently. Hope this script would be useful for you as well.
DECLARE @BACKUPFILENAME VARCHAR(MAX) = ''
DECLARE @MDFLOGICALNAME NVARCHAR(100)
DECLARE @LDFLOGICALNAME NVARCHAR(100)
DECLARE @DEST_PATH NVARCHAR(100)
DECLARE @SQL NVARCHAR(MAX)
DECLARE @DATABASENAME SYSNAME
DROP TABLE IF EXISTS #TFILELISTONLY,#TRAILUPGRADEBACKUPFILES
CREATE TABLE #TRAILUPGRADEBACKUPFILES (ID INT IDENTITY(1,1),FILENAME SYSNAME,RESTORE_DRIVE CHAR(1))
/*********************************************************************************************************************************/
--The below code fetches the file list(backup file names) to be restored from the pre-defined folder
DECLARE @CommandShell TABLE ( Line VARCHAR(512))
DECLARE @CMD VARCHAR(512) ,@BackupFilePath NVARCHAR(256)
SET @BackupFilePath = 'C:\'
SET @CMD = 'DIR /B ' + @BackupFilePath + ' /TC'
INSERT INTO @CommandShell EXEC MASTER..xp_cmdshell @CMD
-- Delete lines not containing filename
DELETE
FROM @CommandShell
WHERE Line is null
If((Select Top 1 Line From @CommandShell) = 'Access is denied.')
PRINT 'Folder access is not provided for network path'
INSERT INTO #TRAILUPGRADEBACKUPFILES (FILENAME)
Select * From @CommandShell A WHERE CHARINDEX('.BAK',LINE) > 0
--Cleanup of system databases
Delete From #TRAILUPGRADEBACKUPFILES where Filename in( 'master.bak','msdb.bak','model.bak','tempdb.bak','resource.bak'
--Add if you have any special list to be ignored (examples as below)
--,'DBAMaintenance.bak','DBATools.bak'
)
/*********************************************************************************************************************************/
CREATE TABLE #TFILELISTONLY
(
TLOGINNAME SYSNAME,TPHYSICALNAME VARCHAR(MAX),
TTYPE VARCHAR(1),TFILEGROUPNAME VARCHAR(MAX),
TSIZE BIGINT,TMAXSIZE BIGINT,TFIELD VARCHAR(MAX),
TCREATELSN VARCHAR(MAX),TDROPLSN VARCHAR(MAX),
TUNIQUEID VARCHAR(MAX),READONLYLSN VARCHAR(MAX),
READWRITELSN VARCHAR(MAX),BACKUPSIZEINBYTES VARCHAR(MAX),
SOURCEBLOCKSIZE VARCHAR(MAX),FILEGROUPID VARCHAR(MAX),
LOGGROUPGUID VARCHAR(MAX),DIFFERENTIALLSN VARCHAR(MAX),
DIFFERENTIALBASEGUID VARCHAR(MAX),ISREADONLY VARCHAR(MAX),
ISPRESENT VARCHAR(MAX),TDEHUMBPRINT VARCHAR(MAX),
SNAPSHORTURL VARCHAR(MAX) -- Add this for higher version of SQL Server
)
WHILE EXISTS(SELECT 1 FROM #TRAILUPGRADEBACKUPFILES)
BEGIN
SET @BACKUPFILENAME = (SELECT TOP 1 FILENAME FROM #TRAILUPGRADEBACKUPFILES ORDER BY FILENAME ASC)
--Restore Path needs to be provided in the below
SET @DEST_PATH = 'C:\DATA\'
SET @DATABASENAME = (SUBSTRING(@BACKUPFILENAME,0,CHARINDEX('.',@BACKUPFILENAME)))
--To check if the database is already present in the environment, If present, Drop the database
IF Exists(SELECT 1 FROM master.sys.databases WHERE name = @DATABASENAME)
BEGIN
EXEC('DROP Database '+@DATABASENAME)
Print @BACKUPFILENAME + ' has been successfully dropped.'
END
INSERT INTO #TFILELISTONLY
EXEC ('RESTORE FILELISTONLY FROM DISK ='''+ @BackupFilePath + @BACKUPFILENAME+'''')
SET @MDFLOGICALNAME = (SELECT TLOGINNAME FROM #TFILELISTONLY WHERE TTYPE ='D')
SELECT @LDFLOGICALNAME = (SELECT TLOGINNAME FROM #TFILELISTONLY WHERE TTYPE ='L')
SELECT @SQL ='RESTORE DATABASE ' + @DATABASENAME + ' FROM DISK = ''' + @BackupFilePath + @BACKUPFILENAME + '''
WITH MOVE ''' + @MDFLOGICALNAME + ''' TO ''' + @DEST_PATH + @DATABASENAME + '.MDF'',
MOVE ''' + + @LDFLOGICALNAME + ''' TO ''' + @DEST_PATH + @DATABASENAME + '.LDF'''
EXEC (@SQL)
Print @BACKUPFILENAME + ' has been successfully restored.'
EXEC ('ALTER DATABASE [' + @DATABASENAME + '] SET RECOVERY SIMPLE;')
DELETE FROM #TFILELISTONLY
DELETE FROM #TRAILUPGRADEBACKUPFILES WHERE FILENAME =@BACKUPFILENAME
END
One thought on “T-SQL Script to restore backup files from a folder in SQL Server”