The other day I found myself in the position of needing to restore multiple databases to a server. In this case all the log files would be on one drive and all the data files on another. Rather than sit there and write restore scripts for ~20 databases I figured it would be quicker to create a quick wrapper that I could just pass the filename into a then let nature take its course.
This is very basic, no restore performance tuning enhancements for example, however it does just the job that I need it to.
If I was smart I would have made this a stored procedure and then iterated through the list of backups in the directory using powershell and then executed the proc for each one. Maybe next time.
Anyhow, view the script below or download Database Restores Generic.sql
SET NOCOUNT ON
DECLARE @File NVARCHAR(1000) = N'MyDatabase.bak'
DECLARE @Path NVARCHAR(1000) = N'D:SQLBackups'
DECLARE @MDFPath NVARCHAR(1000) = 'E:MSSQLData'
DECLARE @LDFPath NVARCHAR(1000) = 'L:MSSQLLogs'
DECLARE @FullLoc NVARCHAR(2000)= @Path + @File
DECLARE @DatabaseName NVARCHAR(128)
DECLARE @RestoreMDF NVARCHAR(2000)
DECLARE @RestoreLDF NVARCHAR(2000)
DECLARE @RestoreCommandFull NVARCHAR(4000)
DECLARE @sqlexec NVARCHAR(4000)
DECLARE @MDFID INT
DECLARE @LDFID INT
DECLARE @MDFName NVARCHAR(128)
DECLARE @LDFName NVARCHAR(128)
DECLARE @RestoreFiles TABLE
(
ID INT IDENTITY(1,1),
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) , UniqueID UNIQUEIDENTIFIER ,
ReadOnlyLSN NUMERIC(25, 0) , ReadWriteLSN NUMERIC(25, 0) , BackupSizeInBytes BIGINT , SourceBlockSize INT , FileGroupID INT ,
LogGroupGUID UNIQUEIDENTIFIER , DifferentialBaseLSN NUMERIC(25, 0) , DifferentialBaseGUID UNIQUEIDENTIFIER ,
IsReadOnly BIT , IsPresent BIT , TDEThumbprint VARBINARY(32)
)
DECLARE @RestoreHeader TABLE
(
BackupName NVARCHAR(128), BackupDescription NVARCHAR(255), BackupType SMALLINT, ExpirationDate DATETIME,
Compressed CHAR(1), 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, CompatabilityLevel 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), RecoveryModel NVARCHAR(60), DifferentialBaseLSN NUMERIC(25,0),
DifferentialBaseGUID UNIQUEIDENTIFIER, BackupTypeDescription NVARCHAR(60), BackupSetGUID UNIQUEIDENTIFIER,
CompressedBackupSize BIGINT
)
SELECT @sqlexec = 'RESTORE FILELISTONLY FROM DISK = ''' + @FullLoc + ''''
INSERT INTO @RestoreFiles EXEC (@sqlexec)
SELECT @sqlexec = 'RESTORE HEADERONLY FROM DISK = ''' + @FullLoc + ''''
INSERT INTO @RestoreHeader EXEC (@sqlexec)
SELECT @DatabaseName = DatabaseName FROM @RestoreHeader
SELECT @MDFID = MIN(ID) FROM @RestoreFiles WHERE [Type] != 'L'
WHILE @MDFID IS NOT NULL
BEGIN
IF @MDFID = 1
BEGIN
SELECT @RestoreMDF = 'WITH MOVE ' + CHAR(39) + LogicalName + CHAR(39) + ' TO ' + CHAR(39) + @MDFPath + REVERSE(LEFT(REVERSE(PhysicalName), CHARINDEX('', REVERSE(PhysicalName))-1)) + CHAR(39) + CHAR(13) FROM @RestoreFiles WHERE ID = @MDFID
END
ELSE
BEGIN
SELECT @RestoreMDF = @RestoreMDF + ', MOVE ' + CHAR(39) + LogicalName + CHAR(39) + ' TO ' + CHAR(39) + @MDFPath + REVERSE(LEFT(REVERSE(PhysicalName), CHARINDEX('', REVERSE(PhysicalName))-1)) + CHAR(39) FROM @RestoreFiles WHERE ID = @MDFID
END
SELECT @MDFID = MIN(ID) FROM @RestoreFiles WHERE ID > @MDFID AND [Type] != 'L'
END
SELECT @LDFID = MIN(ID) FROM @RestoreFiles WHERE [Type] = 'L'
WHILE @LDFID IS NOT NULL
BEGIN
SELECT @RestoreLDF = ISNULL(@RestoreLDF,'') + ', MOVE ' + CHAR(39) +LogicalName + CHAR(39) + ' TO ' + CHAR(39) + @LDFPath + REVERSE(LEFT(REVERSE(PhysicalName), CHARINDEX('', REVERSE(PhysicalName))-1)) + CHAR(39) FROM @RestoreFiles WHERE ID = @LDFID
SELECT @LDFID = MIN(ID) FROM @RestoreFiles WHERE ID > @LDFID AND [Type] = 'L'
END
SELECT @RestoreCommandFull = 'RESTORE DATABASE ' + QUOTENAME(@DatabaseName) + ' ' + CHAR(13) + 'FROM DISK = ''' + @FullLoc + '''' + CHAR(13)
SELECT @RestoreCommandFull = @RestoreCommandFull + @RestoreMDF + @RestoreLDF + CHAR(13) + ', NORECOVERY, STATS=20;'
--PRINT @RestoreCommandFull
EXEC (@RestoreCommandFull)
The link to optomized restores is broken.
LikeLike
Yeah, moved everything away from my old proviers and haven’t migrated the scripts yet.
LikeLike