One of those "busy work" tasks for a Dynamics GP consultant is when we need to create a test company and copy a live database into the test company. Well, I'm not about to automate the creating of the company in GP Utilities, but I can certainly help with the part of backing up and restoring the live database into the test company and running the Microsoft CreateTestCompany.sql script afterwards.
This tried and tested script will perform the following:
- (Optional) Back up the live company database
- (Optional) Back up the test company database
- Restore the live company backup (or, alternately, any specified backup file) over the test company database
- Run Microsoft's CreateTestCompany.sql script against the test company database
- (Optional) Change the posting output options to Screen instead of Printer or File
DECLARE @SourceDatabase varchar(10), @TESTDatabase varchar(10), @DatabaseFolder varchar(1000), @BackupFolder varchar(1000), @BackupFilename varchar(100), @UseRestoreFile tinyint, @RestoreFile varchar(100), @TESTBackupFilename varchar(100), @BackupTESTFirst tinyint, @LogicalFilenameDB varchar(100), @LogicalFilenameLog varchar(100), @SetPrintToScreen tinyint, @SQL varchar(max) ----------------------------------------------------------------------- -- Set up all the information here for the live and test database names ----------------------------------------------------------------------- SET @SourceDatabase = 'TWO' USE [TWO] -- enter the Source Database between the braces SET @TESTDatabase = 'TEST' SET @BackupFolder = 'D:\Program Files\Microsoft SQL Server\MSSQL\BACKUP\' --end with a backslash (\) -- Folder where you want to save the backup file SET @UseRestoreFile = 0 -- 0 = Create a backup and restore it -- -- 1 = Use the below filename to restore from instead of creating new backup -- Use this when you just want to reload a backup you already created SET @RestoreFile = 'TWO_20110111.bak' SET @BackupTESTFirst = 1 -- 0 = No; 1 = Yes -- Backup the TEST database before restoring -- You should do this the first time you restore per day SET @SetPrintToScreen = 1 -- 0 = No; 1 = Yes -- Change the posting output to the screen instead of the printer ----------------------------------------------------------------------- ----------------------------------------------------------------------- ----------------------------------------------------------------------- SELECT @LogicalFilenameDB = (rtrim(name)) FROM dbo.sysfiles WHERE groupid = 1 SELECT @LogicalFilenameLog = (rtrim(name)) FROM dbo.sysfiles WHERE groupid = 0 SELECT @DatabaseFolder = left(filename,len(filename)-charindex('\',reverse(filename))+1) FROM dbo.sysfiles WHERE groupid = 1 print @LogicalFilenameDB print @LogicalFilenameLog print @DatabaseFolder SET @SQL = '' IF @UseRestoreFile = 0 BEGIN SET @BackupFilename = @BackupFolder + @SourceDatabase + '_' + convert(varchar(4),year(GETDATE())) + right('00' + convert(varchar(2),month(GETDATE())),2) + right('00' + convert(varchar(2),day(GETDATE())),2) + '_' + replace(CONVERT(VARCHAR(8),GETDATE(),108),':','') + '_for_' + @TESTDatabase + '.bak' END ELSE BEGIN SET @BackupFilename = @BackupFolder + @RestoreFile END print '.' print 'Backup Filename: ' + @BackupFilename print '.' SET @TESTBackupFilename = @BackupFolder + @TESTDatabase + '_' + convert(varchar(4),year(GETDATE())) + right('00' + convert(varchar(2),month(GETDATE())),2) + right('00' + convert(varchar(2),day(GETDATE())),2) + '_' + replace(CONVERT(VARCHAR(8),GETDATE(),108),':','') + '_pre_LIVE_restore.bak' -- check to see if the TEST database is in use first IF EXISTS(SELECT loginame=rtrim(loginame),hostname,dbname = (CASE WHEN dbid = 0 THEN NULL WHEN dbid <> 0 THEN db_name(dbid) END) FROM master.dbo.sysprocesses WHERE CASE WHEN dbid = 0 THEN NULL WHEN dbid <> 0 THEN db_name(dbid) END = @TESTDatabase) BEGIN PRINT 'The database is in use' SELECT loginame=rtrim(loginame),hostname,dbname = (CASE WHEN dbid = 0 THEN NULL WHEN dbid <> 0 THEN db_name(dbid) END) FROM master.dbo.sysprocesses WHERE CASE WHEN dbid = 0 THEN NULL WHEN dbid <> 0 THEN db_name(dbid) END = @TESTDatabase END ELSE BEGIN IF @UseRestoreFile = 0 BEGIN -- Back up the LIVE database SET @SQL = '' + 'PRINT ''Backing up Source database (' + @SourceDatabase + ')''; ' + 'BACKUP DATABASE [' + @SourceDatabase + '] TO DISK ' + '= N''' + @BackupFilename + ''' ' + 'WITH NOFORMAT, NOINIT, NAME ' + '= N''' + @SourceDatabase + '-Full Database Backup'', SKIP, NOREWIND, NOUNLOAD, STATS = 10' EXEC (@SQL) END -- Back up the TEST database IF @BackupTESTFirst = 1 BEGIN SET @SQL = '' + 'PRINT ''Backing up Destination database (' + @TESTDatabase + ')''; ' + 'BACKUP DATABASE [' + @TESTDatabase + '] TO DISK ' + '= N''' + @TESTBackupFilename + ''' ' + 'WITH NOFORMAT, NOINIT, NAME ' + '= N''' + @TESTDatabase + '-Full Database Backup'', SKIP, NOREWIND, NOUNLOAD, STATS = 10' EXEC (@SQL) END -- Restore to the TEST database SET @SQL = '' + 'PRINT ''Restoring to Destination database (' + @TESTDatabase + ')''; ' + 'RESTORE DATABASE [' + @TESTDatabase + '] FROM DISK ' + '= N''' + @BackupFilename + ''' ' + 'WITH FILE = 1, ' + 'MOVE N''' + @LogicalFilenameDB + ''' TO ' + 'N''' + @DatabaseFolder + 'GPS' + @TESTDatabase + 'Dat.mdf'', ' + 'MOVE N''' + @LogicalFilenameLog + ''' TO ' + 'N''' + @DatabaseFolder + 'GPS' + @TESTDatabase + 'Log.ldf'', ' + 'NOUNLOAD, REPLACE, STATS = 10' EXEC (@SQL) SET @SQL = '' + 'PRINT ''Setting Recovery Model to Simple''; ' + 'ALTER DATABASE [' + @TESTDatabase + '] SET RECOVERY SIMPLE WITH NO_WAIT' EXEC (@SQL) SET @SQL = '' + 'PRINT ''Shrinking Log File'' ' + 'USE [' + @TESTDatabase + '] ' + 'DBCC SHRINKFILE (N''' + @LogicalFilenameLog + ''' , 0, TRUNCATEONLY)' EXEC (@SQL) IF @SetPrintToScreen = 1 BEGIN SET @SQL = '' + 'PRINT ''Setting output to print to screen instead of printer'' ' + 'USE [' + @TESTDatabase + '] ' + 'UPDATE SY02200 SET PRTOSCNT = 1, PRTOPRNT = 0' EXEC (@SQL) END -- Run the CreateTestCompany script from MS SET @SQL = '' + 'PRINT ''Running CreateTestCompany script on ' + @TESTDatabase + '''; ' + 'USE [' + @TESTDatabase + '] ' + 'if not exists(select 1 from tempdb.dbo.sysobjects where name = ''##updatedTables'') ' + ' create table [##updatedTables] ([tableName] char(100)) ' + 'truncate table ##updatedTables ' + 'declare @cStatement varchar(255) ' + 'declare G_cursor CURSOR for ' + 'select ' + 'case ' + 'when UPPER(a.COLUMN_NAME) in (''COMPANYID'',''CMPANYID'') ' + ' then ''update ''+a.TABLE_NAME+'' set ''+a.COLUMN_NAME+'' = ''+ cast(b.CMPANYID as char(3)) ' + 'else ' + '''update ''+a.TABLE_NAME+'' set ''+a.COLUMN_NAME+'' = ''''''+ db_name()+'''''''' ' + 'end ' + 'from INFORMATION_SCHEMA.COLUMNS a, DYNAMICS.dbo.SY01500 b, INFORMATION_SCHEMA.TABLES c ' + 'where UPPER(a.COLUMN_NAME) in (''COMPANYID'',''CMPANYID'',''INTERID'',''DB_NAME'',''DBNAME'', ''COMPANYCODE_I'') ' + 'and b.INTERID = db_name() and a.TABLE_NAME = c.TABLE_NAME and c.TABLE_CATALOG = db_name() and c.TABLE_TYPE = ''BASE TABLE''; ' + 'set nocount on; ' + 'OPEN G_cursor; ' + 'FETCH NEXT FROM G_cursor INTO @cStatement ' + 'WHILE (@@FETCH_STATUS <> -1) ' + 'begin ' + 'insert ##updatedTables select ' + 'substring(@cStatement,8,patindex(''%set%'',@cStatement)-9) ' + 'Exec (@cStatement) ' + 'FETCH NEXT FROM G_cursor INTO @cStatement ' + 'end ' + 'DEALLOCATE G_cursor ' + 'select [tableName] as ''Tables that were Updated'' from ##updatedTables ' EXEC (@SQL) PRINT 'Don''t forget to run GP SQL Maintenance on the ' + @TESTDatabase + ' database.' END
No comments:
Post a Comment