Since the release of Microsoft Dynamics GP 2018, on the 1st December 2018, we have been busy with a few upgrade projects for clients. Our standard recommendation is to have a standalone test system for performing UAT and this means backing up and restoring databases.
While the backups are easy to do, the restores can be trickier when one database has been restored into another, as this means the logical file name will not match the physical one.
This isn’t an issue when the client has only a handful of databases, but when there are 30 or even a hundred, it becomes much more of an issue. However, you can select database details in SQL Server from the sys.master_files single, system-wide view.
This script creates restore scripts for all Dynamics GP databases and will use the correct logical filename whether it matches the . The script is configured with the assumption that the system database is called DYNAMICS; if you are using a named system database, change the highlighted section:
/*
Created by Ian Grieve of azurecurve|Ramblings of a Dynamics GP Consultant (https://www.azurecurve.co.uk)
This code is licensed under the Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International (CC BY-NC-SA 4.0 Int).
*/
USE DYNAMICS
GO
DECLARE @BackupLocation VARCHAR(300) = 'I:\Live Upgrade\2016R2\'
DECLARE @DataLocation VARCHAR(300) = 'S:\Data\'
DECLARE @LogLocation VARCHAR(300) = 'L:\Logs\'
DECLARE @DateParameter VARCHAR(10) = FORMAT(GETDATE(), 'yyyy-MM-dd')
DECLARE @SQLStatement NVARCHAR(MAX)
SELECT @SQLStatement = '
USE master
GO
RESTORE DATABASE ' + DB_NAME() + ' FROM
DISK = N''' + @BackupLocation + DB_NAME() + '_' + @DateParameter + '.bak'' WITH FILE = 1,
MOVE N''' + ['databases-data'].name + ''' TO N''' + @DataLocation + RIGHT(['databases-data'].physical_name, CHARINDEX('\', REVERSE(['databases-data'].physical_name)) - 1) + ''',
MOVE N''' + ['databases-log'].name + ''' TO N''' + @LogLocation + RIGHT(['databases-log'].physical_name, CHARINDEX('\', REVERSE(['databases-log'].physical_name)) - 1) + ''', NOUNLOAD, STATS = 5
GO
'
FROM
sys.master_files AS ['databases-data']
INNER JOIN
sys.master_files AS ['databases-log']
ON
DB_NAME(['databases-log'].database_id) = DB_NAME(['databases-data'].database_id)
WHERE
DB_NAME(['databases-data'].database_id) = DB_NAME() and ['databases-data'].name like '%.mdf'
SELECT @SQLStatement = @SQLStatement +
'RESTORE DATABASE ' + RTRIM(['Company Master'].INTERID) + ' FROM
DISK = N''' + @BackupLocation + RTRIM(['Company Master'].INTERID) + '_' + @DateParameter + '.bak'' WITH FILE = 1,
MOVE N''' + ['databases-data'].name + ''' TO N''' + @DataLocation + RIGHT(['databases-data'].physical_name, CHARINDEX('\', REVERSE(['databases-data'].physical_name)) - 1) + ''',
MOVE N''' + ['databases-log'].name + ''' TO N''' + @LogLocation + RIGHT(['databases-log'].physical_name, CHARINDEX('\', REVERSE(['databases-log'].physical_name)) - 1) + ''', NOUNLOAD, STATS = 5
GO
'
FROM
SY01500 AS ['Company Master']
INNER JOIN
sys.master_files AS ['databases-data']
ON
DB_NAME(['databases-data'].database_id) = ['Company Master'].INTERID AND ['databases-data'].name LIKE '%mdf'
INNER JOIN
sys.master_files AS ['databases-log']
ON
DB_NAME(['databases-log'].database_id) = ['Company Master'].INTERID AND ['databases-log'].name LIKE '%ldf'
WHERE
['databases-data'].name NOT LIKE '%<TEST>'
AND
['Company Master'].CMPANYID > 0
ORDER BY
['Company Master'].INTERID
,['databases-data'].name
SELECT @SQLStatement
Click to show/hide the Logical File Name SQL Scripts Series Index
What should we write about next?
If there is a topic which fits the typical ones of this site, which you would like to see me write about, please use the form, below, to submit your idea.
1 thought on “Logical File Name SQL Scripts: SQL Script to Create Restore Scripts for all Dynamics Databases”