Getting your Trinity Audio player ready...
|
Todo mundo merece uma segunda chance,, ou para fazer melhor, ou para simplesmente não fazer,,, então,,, até no SQL temos uma segunda chance…
Dessa vez o Sr. David Howard (Blog | Twitter) deu a oportunidade de escrevermos novamente sobre algum tópico anterior do T-SQL Tuesday, ou para melhora-lo ou para fazer um se você não participou…
Eu resolvi melhorar o meu script para montar um Mirror com SQLCMD,,, na versão anterior (#25) se o banco de dados tiver mais que um datafile você tem que modificar o script na mão e compensar a criação desse outro arquivo… Nesta versão o script vai ler o arquivo de backup em uma temp table e montar o script de restore com todas as variáveis…
Vale lembrar que você precisa habilitar a opção de SQLCMD no SSMS e não esqueça de trocar o caminho do backup…
Everyone deserves a second chance, or to do better or to simply not do, then, even in SQL havea second chance…
This time Mr. David Howard (blog | twitter) gave us the opportunity to write again about a previous topic of Tuesday’s T-SQL, or to improve it or make one if you did not participate …
I decided to improve my script to create a Mirror with SQLCMD, in the previous version (#25) if the database has more than one datafile you have to modify the script and make the creation of another file … this version will read backup file in a temp table and mount the restore script with all the variables …
Remember that you need to enable the option of SQLCMD in SSMS and do not forget to change the backup path …
:SETVAR PrincipalServer (local)\INST01 :SETVAR MirrorServer (local)\INST02 :SETVAR SERVER (servername) :SETVAR db DB_NAME go :ON ERROR EXIT go :CONNECT $(PrincipalServer) ALTER DATABASE $(db) SET RECOVERY FULL go CREATE ENDPOINT Mirroring STATE=STARTED AS TCP (LISTENER_PORT=5091) FOR DATABASE_MIRRORING (ROLE=ALL) GO :CONNECT $(MirrorServer) CREATE ENDPOINT Mirroring STATE=STARTED AS TCP (LISTENER_PORT=5092) FOR DATABASE_MIRRORING (ROLE=ALL) GO :CONNECT $(PrincipalServer) BACKUP DATABASE $(db) TO DISK = 'D:\DB01\local\$(db).bak' WITH INIT GO :CONNECT $(MirrorServer) DECLARE @InstanceName sql_variant, @InstanceDir sql_variant, @SQLDataRoot nvarchar(512), @ExecStr nvarchar(max) SELECT @InstanceName = ISNULL(SERVERPROPERTY('InstanceName'), 'MSSQLServer') EXECUTE master.dbo.xp_regread 'HKEY_LOCAL_MACHINE', 'SOFTWARE\Microsoft\Microsoft SQL Server\Instance Names\SQL', @InstanceName, @InstanceDir OUTPUT SELECT @ExecStr = 'EXECUTE master.dbo.xp_regread ' + '''HKEY_LOCAL_MACHINE'', ' + '''SOFTWARE\Microsoft\Microsoft SQL Server\' + convert(varchar, @InstanceDir) + '\Setup'', ''SQLDataRoot'', @SQLDataRoot OUTPUT' EXEC master.dbo.sp_executesql @ExecStr , N'@SQLDataRoot nvarchar(512) OUTPUT' , @SQLDataRoot OUTPUT IF @SQLDataRoot IS NULL BEGIN RAISERROR ('I can´t find where restore the Database... I going to stop...', 16, -1) END CREATE TABLE #BackupFileList ( LogicalName sysname NULL , PhysicalName sysname NULL , [Type] char(1) , FileGroupName sysname NULL , Size bigint , MaxSize bigint , FileId smallint , CreateLSN numeric(25,0) , DropLSN numeric(25,0) , UniqueId uniqueidentifier , ReadOnlyLSN numeric(25,0) , ReadWriteLSN numeric(25,0) , BackupSizeInBytes bigint , SourceBlockSize bigint , FileGroupId smallint , LogGroupGUID uniqueidentifier , DifferentialBaseLSN numeric(25,0) , DifferentialBaseGUID uniqueidentifier , IsReadOnly bit , IsPresent bit , TDEThumbPrint varbinary(32) ) INSERT #BackupFileList EXEC('RESTORE FILELISTONLY FROM DISK = ''D:\DB01\local\$(db).bak''') UPDATE #BackupFileList SET PhysicalName = @SQLDataRoot + N'\Data\' + REVERSE(SUBSTRING(REVERSE(PhysicalName) , 1, PATINDEX('%\%', REVERSE(PhysicalName)) -1)) DECLARE @LogicalName sysname , @PhysicalName sysname DECLARE FileListCursor CURSOR FAST_FORWARD FOR SELECT LogicalName, PhysicalName FROM #BackupFileList OPEN FileListCursor FETCH NEXT FROM FileListCursor INTO @LogicalName, @PhysicalName SELECT @ExecStr = N'RESTORE DATABASE $(db)' + N' FROM DISK = ''D:\DB01\local\$(db).bak''' + N' WITH MOVE ''' + @LogicalName + N''' TO ''' + @PhysicalName + N'''' FETCH NEXT FROM FileListCursor INTO @LogicalName, @PhysicalName WHILE @@FETCH_STATUS <> -1 BEGIN SELECT @ExecStr = @ExecStr + N', MOVE ''' + @LogicalName + ''' TO ''' + @PhysicalName + '''' FETCH NEXT FROM FileListCursor INTO @LogicalName, @PhysicalName END SELECT @ExecStr = @ExecStr + N' , NORECOVERY, REPLACE' -- if you receive the error message because the script don´t found where he need to restore, you can uncomment the next line and get the restore command,,, -- to restore manual... -- SELECT @ExecStr EXEC (@ExecStr) DEALLOCATE FileListCursor GO :CONNECT $(PrincipalServer) SELECT DATABASEPROPERTYEX(N'$(db)', N'Status') AS 'Principal Database State' -- Returns ONLINE SELECT db_name(sd.[database_id]) AS [Database Name], sd.mirroring_guid, sd.mirroring_state, sd.mirroring_state_desc, sd.mirroring_partner_name, sd.mirroring_witness_name, sd.mirroring_witness_state, sd.mirroring_witness_state_desc, sd.mirroring_role, sd.mirroring_role_desc, sd.mirroring_role_sequence, sd.mirroring_safety_level, sd.mirroring_safety_level_desc, sd.mirroring_safety_sequence, sd.mirroring_failover_lsn FROM sys.database_mirroring AS sd WHERE sd.[database_id] = db_id(N'$(db)') go :CONNECT $(MirrorServer) SELECT DATABASEPROPERTYEX(N'$(db)', N'Status') AS 'Mirror Database State' -- Returns RESTORING SELECT db_name(sd.[database_id]) AS [Database Name], sd.mirroring_guid, sd.mirroring_state, sd.mirroring_state_desc, sd.mirroring_partner_name, sd.mirroring_witness_name, sd.mirroring_witness_state, sd.mirroring_witness_state_desc, sd.mirroring_role, sd.mirroring_role_desc, sd.mirroring_role_sequence, sd.mirroring_safety_level, sd.mirroring_safety_level_desc, sd.mirroring_safety_sequence, sd.mirroring_failover_lsn FROM sys.database_mirroring AS sd WHERE sd.[database_id] = db_id(N'$(db)') go :CONNECT $(PrincipalServer) BACKUP LOG $(db) TO DISK = 'D:\DB01\local\$(db)_Log.bak' WITH INIT GO :CONNECT $(MirrorServer) RESTORE LOG $(db) FROM DISK = 'D:\DB01\local\$(db)_Log.bak' WITH NORECOVERY GO ALTER DATABASE $(db) SET PARTNER = 'TCP://$(server):5091' GO :CONNECT $(PrincipalServer) ALTER DATABASE $(db) SET PARTNER = 'TCP://$(server):5092' GO SELECT db_name(sd.[database_id]) AS [Database Name], sd.mirroring_guid, sd.mirroring_state, sd.mirroring_state_desc, sd.mirroring_partner_name, sd.mirroring_witness_name, sd.mirroring_witness_state, sd.mirroring_witness_state_desc, sd.mirroring_role, sd.mirroring_role_desc, sd.mirroring_role_sequence, sd.mirroring_safety_level, sd.mirroring_safety_level_desc, sd.mirroring_safety_sequence, sd.mirroring_failover_lsn FROM sys.database_mirroring AS sd WHERE sd.[database_id] = db_id(N'$(db)') GO
Thanks for participating in T-SQL Tuesday, Ricardo!