Quick Contact

Backup resotre multiple bak files from directory

 

Exporting/Importing multiple databases – different MSSQL versions
Document created by: Daniel Engelman, 17.7.13

 

Possible purposes for this script:

  1. Restore large amounts of “.bak” files between different SQL versions.
  2. Automatically Backup/Restore databases for manual redundancy procedures.

 

Contents:

 

Uniform logical database names in source server.....................................................................................2

Backup all user databases in source server............................................................................................4

Copy all relevant SQL users with SID to prevent orphaned sql users................................................................6

Restoring Databases on Destination server...........................................................................................8

 

 

 

 

Uniform logical database names in source server


General task explanation:
When creating a new database, by default it is being assigned with logical names for the actual files according to the Database Name. For example – in the database below “xglobedb”, you can see to logical names opened automatically (xglobedb & xglobedb_log).

אורלי

So, for new databases – all nice and peachy.

The problem is that if a database has been copiedor restored from a .bak file the client uploaded himself and was not normalized, it will contain the wrong logical name. This will be problematic later for the import script.

For example – you can see some inconsistencies below –
 “keeper_phone” and “keeper_birds” both have the same logical names: “DataMining2013” – this is probably because they were copied from the same database twice.
“keeper_dogs” was probably restored from a client-uploaded “.bak” file without normalization.

SELECT name, type_desc, physical_name AS current_file_location
FROM sys.master_files

אורלי1 

Therefore, we must first fix all logical names for the databases.
Here is a manual example of how to change the LogicalName of “keeper_phone” database:

1. Properties on the database name

אורלי 2

2. Change the “Logical Name” according to the “File Name”

אורלי3

3. You can see it is now ok and “uniform” and continue to the next step :)

אורלי4

Backup all user databases in source server

General Task explanation: back up all existing user databases (without system databases) to local drive on source server.

In this example I have used “C:\SQLMigration” and gave “SQLUser” SQL service the required permissions to write into that directory.

1. Verify there is enough disk space for all databases.

אורלי5

2. Open Directory “C:\SQLMigration” and give “SQLUser” write permissions

אורלי6

3. Change the “@path” variable to the correct path you have created in the previous step and run the script, it will create “bak” files of all user databases.

DECLARE @name VARCHAR(50) -- database name  
DECLARE @path VARCHAR(256) -- path for backup files  
DECLARE @fileName VARCHAR(256) -- filename for backup  
DECLARE @fileDate VARCHAR(20) -- used for file name

 
-- specify database backup directory
SET @path = 'C:\SQLMigration\'  

 
-- specify filename format
SELECT @fileDate = CONVERT(VARCHAR(20),GETDATE(),112) 

 
DECLARE db_cursor CURSOR FOR  
SELECT name 
FROM master.dbo.sysdatabases 
WHERE name NOT IN ('master','model','msdb','tempdb')  -- exclude these databases

 
OPEN db_cursor   
FETCH NEXT FROM db_cursor INTO @name   

 
WHILE @@FETCH_STATUS = 0   
BEGIN   
       SET @fileName = @path + @name + '.BAK'  
       BACKUP DATABASE @name TO DISK = @fileName  

 
       FETCH NEXT FROM db_cursor INTO @name   
END   

 
CLOSE db_cursor   
DEALLOCATE db_cursor

אורלי7 

Copy all relevant SQL users with SID to prevent orphaned sql users

General Task Description: It is possible to migrate the SQL Users along with the password (even if you don’t know it) and with its original SID and to have it recreated at the destination SQL server. This means there will be no “orphaned” users and you won’t need to create logins / password reset anything. Pretty neat.

1. Run the following script:

SELECT
'create login [' + p.name + '] ' +  
case when p.type in('U','G') then 'from windows ' else '' end +
'with ' +
case when p.type = 'S' then 'password = ' + master.sys.fn_varbintohexstr(l.password_hash) + ' hashed, ' +
'sid = ' + master.sys.fn_varbintohexstr(l.sid) + ', check_expiration = ' +
case when l.is_policy_checked > 0 then 'OFF, ' else 'OFF, ' end + 'check_policy = ' + case when l.is_expiration_checked > 0 then 'OFF, ' else 'OFF, ' end +
case when l.credential_id > 0 then 'credential = ' + c.name + ', ' else '' end  
else '' end +
'default_database = master ' +
case when len(p.default_language_name) > 0 then ', default_language = ' + p.default_language_name else '' end
FROM sys.server_principals p
LEFT JOIN sys.sql_logins l
ON p.principal_id = l.principal_id
LEFT JOIN sys.credentials c
ON  l.credential_id = c.credential_id
WHERE p.type in('S')
AND p.name <> 'sa'

2. The script result will be a ready “create login” statement you should run on the destination server later on. You should copy only the relevant users.

אורלי8

3. Run the relevant “create login” statements on the destination server, you will notice it has added the new logins under “Security > Logins”

אורלי9

 

Restoring Databases on Destination server

General Task Description: Now, that all logins has been created and all .bak files are located in a directory of your choosing (c:\sqlmigration in this example) we can run the import script.

1. For the first time only – please run the following command through SQL Management Studio on the Destination SQL Server to create the [sp_RestoreFromAllFilesInDirectory] stored procedure.

CREATE PROC [dbo].[sp_RestoreFromAllFilesInDirectory] 
@SourceDirBackupFiles nvarchar(200), @DestDirDbFiles nvarchar(200),@DestDirLogFiles nvarchar(200) 
AS 
--Originally written by Tibor Karaszi 2004. Use at own risk. 
--Restores from all files in a certain directory. Assumes that: 
--  There's only one backup on each backup device. 
--  Each database uses only two database files and the mdf file is returned first from the RESTORE FILELISTONLY command. 
--Sample execution: 
-- EXEC sp_RestoreFromAllFilesInDirectory 'C:\Mybakfiles\', 'D:\Mydatabasesdirectory\' ,’C:\MylogDirectory\’ 
SET NOCOUNT ON 

--Table to hold each backup file name in 
CREATE TABLE #files(fname varchar(200),depth int, file_ int) 
INSERT #files 
EXECUTE master.dbo.xp_dirtree @SourceDirBackupFiles, 1, 1 

--Table to hold the result from RESTORE HEADERONLY. Needed to get the database name out from 
CREATE TABLE #bdev( 
 BackupName nvarchar(128) 
,BackupDescription nvarchar(255) 
,BackupType smallint 
,ExpirationDate datetime 
,Compressed tinyint 
,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 int 
,IsSnapshot int 
,IsReadOnly int 
,IsSingleUser int 
,HasBackupChecksums int 
,IsDamaged int 
,BegibsLogChain int 
,HasIncompleteMetaData int 
,IsForceOffline int 
,IsCopyOnly int 
,FirstRecoveryForkID uniqueidentifier 
,ForkPointLSN numeric(25,0) 
,RecoveryModel nvarchar(128) 
,DifferentialBaseLSN numeric(25,0) 
,DifferentialBaseGUID uniqueidentifier 
,BackupTypeDescription nvarchar(128) 
,BackupSetGUID uniqueidentifier 
,CompressedBackupSize nvarchar(128)
) 

--Table to hold result from RESTORE FILELISTONLY. Need to generate the MOVE options to the RESTORE command 
CREATE TABLE #dbfiles( 
 LogicalName nvarchar(128) 
,PhysicalName nvarchar(260) 
,Type char(1) 
,FileGroupName nvarchar(128) 
,Size numeric(20,0) 
,MaxSize numeric(20,0) 
,FileId int 
,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) 
,DifferentialBaseGUID uniqueidentifier 
,IsReadOnly int 
,IsPresent int 
,TDEThumbprint nvarchar(128)
) 


DECLARE @fname varchar(200) 
DECLARE @dirfile varchar(300) 
DECLARE @LogicalName nvarchar(128) 
DECLARE @PhysicalName nvarchar(260) 
DECLARE @type char(1) 
DECLARE @DbName sysname 
DECLARE @sql nvarchar(1000) 

DECLARE files CURSOR FOR 
SELECT fname FROM #files 
DECLARE dbfiles CURSOR FOR 


SELECT LogicalName, PhysicalName, Type FROM #dbfiles 

OPEN files 
FETCH NEXT FROM files INTO @fname 
WHILE @@FETCH_STATUS = 0 
BEGIN 
SET @dirfile = @SourceDirBackupFiles + @fname 

--Get database name from RESTORE HEADERONLY, assumes there's only one backup on each backup file. 
TRUNCATE TABLE #bdev 
INSERT #bdev 
EXEC('RESTORE HEADERONLY FROM DISK = ''' + @dirfile + '''') 
SET @DbName = (SELECT DatabaseName FROM #bdev) 

--Construct the beginning for the RESTORE DATABASE command 
SET @sql = 'RESTORE DATABASE ' + @DbName + ' FROM DISK = ''' + @dirfile + ''' WITH MOVE ' 

--Get information about database files from backup device into temp table 
TRUNCATE TABLE #dbfiles 
INSERT #dbfiles 
EXEC('RESTORE FILELISTONLY FROM DISK = ''' + @dirfile + '''') 

OPEN dbfiles 
FETCH NEXT FROM dbfiles INTO @LogicalName, @PhysicalName, @type 
--For each database file that the database uses 
WHILE @@FETCH_STATUS = 0 
BEGIN 
IF @type = 'D' 
SET @sql = @sql + '''' + @LogicalName + ''' TO ''' + @DestDirDbFiles + @LogicalName  + '.mdf'', MOVE ' 
ELSE IF @type = 'L' 
SSET @sql = @sql + '''' + @LogicalName + ''' TO ''' + @DestDirLogFiles + @LogicalName  + '.ldf''' 
FETCH NEXT FROM dbfiles INTO @LogicalName, @PhysicalName, @type 
END 

--Here's the actual RESTORE command 
PRINT @sql 
--Remove the comment below if you want the procedure to actually execute the restore command. 
--EXEC(@sql) 
CLOSE dbfiles 
FETCH NEXT FROM files INTO @fname 
END 
CLOSE files 
DEALLOCATE dbfiles 
DEALLOCATE files

 

2. Now it is time to run the sp_RestoreFromAllFilesInDirectory with the correct parameters as follows:

EXEC sp_RestoreFromAllFilesInDirectory 'C:\SQLMigration\', 'C:\dbs\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\' ,'C:\dbs\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\'

The script will construct a “RESTORE DATABASE” argument which you should copy/paste and run.

אורלי10 (1)

3. Running the constructed script will restore all relevant databases.
You are now good to go – the process has been completed.

אורלי11

 

 

 

Additional Articles
X

Partners

© 2013 XGlobe Online Ltd.