Skip to content

Instantly share code, notes, and snippets.

@jnm2
Last active April 29, 2025 22:18
Show Gist options
  • Save jnm2/3a01b10b46c4cd6b4729e366f7974c73 to your computer and use it in GitHub Desktop.
Save jnm2/3a01b10b46c4cd6b4729e366f7974c73 to your computer and use it in GitHub Desktop.
create or alter proc dbo.RestoreDatabase(@databaseName sysname, @backupFilePath nvarchar(max), @replace bit, @progressPercentIncrement tinyint = 10)
as
set nocount on;
-- Get backup database name
declare @backups table (BackupName nvarchar(128), BackupDescription nvarchar(255), BackupType smallint, ExpirationDate datetime, Compressed binary(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, CompatibilityLevel 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) null, RecoveryModel nvarchar(60), DifferentialBaseLSN numeric(25,0) null, DifferentialBaseGUID uniqueidentifier, BackupTypeDescription nvarchar(60), BackupSetGUID uniqueidentifier null, CompressedBackupSize bigint, containment tinyint not null, KeyAlgorithm nvarchar(32), EncryptorThumbprint varbinary(20), EncryptorType nvarchar(32), LastValidRestoreTime datetime, TimeZone nvarchar(32), CompressionAlgorithm nvarchar(32));
declare @sql nvarchar(max) = 'restore headeronly from disk = N' + quotename(@backupFilePath, '''');
insert @backups execute (@sql);
declare @originalDatabaseName sysname = (select DatabaseName from @backups);
-- Get backup file list
declare @backupFiles table (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) null, UniqueID uniqueidentifier, ReadOnlyLSN numeric(25,0) null, ReadWriteLSN numeric(25,0) null, BackupSizeInBytes bigint, SourceBlockSize int, FileGroupID int, LogGroupGUID uniqueidentifier null, DifferentialBaseLSN numeric(25,0) null, DifferentialBaseGUID uniqueidentifier, IsReadOnly bit, IsPresent bit, TDEThumbprint varbinary(32), SnaphotURL nvarchar(360));
set @sql = 'restore filelistonly from disk = N' + quotename(@backupFilePath, '''');
insert @backupFiles execute (@sql);
-- Build restore command
set @sql =
'if db_id(' + quotename(@databaseName, '''') + ') is not null
alter database ' + quotename(@databaseName) + ' set single_user with rollback immediate;
restore database ' + quotename(@databaseName) + ' from disk = ' + quotename(@backupFilePath, '''') + ' with';
select @sql += '
move ' + quotename(LogicalName, '''') + ' to ' + quotename(
cast(serverproperty(iif(Type = 'L', 'instancedefaultlogpath', 'instancedefaultdatapath')) as nvarchar(max)) +
iif(FileName like '%' + @originalDatabaseName + '%',
replace(FileName, @originalDatabaseName, @databaseName),
@databaseName + iif(Type = 'L', '_log.ldf', '.mdf'))
, '''') + ',' from (
select LogicalName, right(PhysicalName, charindex('\', reverse(PhysicalName)) - 1) as FileName, Type
from @backupFiles
) as BackupFiles;
if @replace = 1 set @sql += '
replace,';
set @sql += '
stats = ' + format(@progressPercentIncrement, '0') + ';';
execute (@sql);
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment