Monday, February 15, 2016

Failover and Failback in Logshipping (MSSQL Server 2008 R2)

   Database State & Jobs on Primary & Secondary Server:


    Database State on Primary Server (bhamare3):

 Database State on Secondary Server (bhamare3\Named):
  Log shipping jobs on Primary & Secondary Server:

·         Log shipping Jobs on Primary Server (bhamare3):


         Log shipping Jobs on Secondary Server (bhamare3\Named):



·         Check the log shipping is in sync by executing following query on Secondary Server (bhamare3\Named).


select secondary_database,last_copied_file,last_restored_file from msdb..log_shipping_monitor_secondary




·         You can generate the log shipping sync report on Secondary Server (bhamare3\Named)  by

Right click on Instance Name > Reports > Standard Reports > Transaction Log shipping status




   Backup Logins:

If you simply want to make a backup of your SQL Server Logins for disaster recovery purposes
 just follow these easy steps:

On the Primary server (bhamare3) launch SQL Management Studio & connect to the instance of SQL Server.

USE master
GO
IF OBJECT_ID ('sp_hexadecimal') IS NOT NULL
  DROP PROCEDURE sp_hexadecimal
GO
CREATE PROCEDURE sp_hexadecimal
    @binvalue varbinary(256),
    @hexvalue varchar (514) OUTPUT
AS
DECLARE @charvalue varchar (514)
DECLARE @i int
DECLARE @length int
DECLARE @hexstring char(16)
SELECT @charvalue = '0x'
SELECT @i = 1
SELECT @length = DATALENGTH (@binvalue)
SELECT @hexstring = '0123456789ABCDEF'
WHILE (@i <= @length)
BEGIN
  DECLARE @tempint int
  DECLARE @firstint int
  DECLARE @secondint int
  SELECT @tempint = CONVERT(int, SUBSTRING(@binvalue,@i,1))
  SELECT @firstint = FLOOR(@tempint/16)
  SELECT @secondint = @tempint - (@firstint*16)
  SELECT @charvalue = @charvalue +
    SUBSTRING(@hexstring, @firstint+1, 1) +
    SUBSTRING(@hexstring, @secondint+1, 1)
  SELECT @i = @i + 1
END

SELECT @hexvalue = @charvalue
GO

IF OBJECT_ID ('sp_help_revlogin') IS NOT NULL
  DROP PROCEDURE sp_help_revlogin
GO
CREATE PROCEDURE sp_help_revlogin @login_name sysname = NULL AS
DECLARE @name sysname
DECLARE @type varchar (1)
DECLARE @hasaccess int
DECLARE @denylogin int
DECLARE @is_disabled int
DECLARE @PWD_varbinary  varbinary (256)
DECLARE @PWD_string  varchar (514)
DECLARE @SID_varbinary varbinary (85)
DECLARE @SID_string varchar (514)
DECLARE @tmpstr  varchar (1024)
DECLARE @is_policy_checked varchar (3)
DECLARE @is_expiration_checked varchar (3)

DECLARE @defaultdb sysname

IF (@login_name IS NULL)
  DECLARE login_curs CURSOR FOR

      SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM
sys.server_principals p LEFT JOIN sys.syslogins l
      ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name <> 'sa'
ELSE
  DECLARE login_curs CURSOR FOR


      SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM
sys.server_principals p LEFT JOIN sys.syslogins l
      ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name = @login_name
OPEN login_curs

FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess,@denylogin
IF (@@fetch_status = -1)
BEGIN
  PRINT 'No login(s) found.'
  CLOSE login_curs
  DEALLOCATE login_curs
  RETURN -1
END
SET @tmpstr = '/* sp_help_revlogin script '
PRINT @tmpstr
SET @tmpstr = '** Generated ' + CONVERT (varchar, GETDATE()) + ' on ' + @@SERVERNAME + ' */'
PRINT @tmpstr
PRINT ''
WHILE (@@fetch_status <> -1)
BEGIN
  IF (@@fetch_status <> -2)
  BEGIN
    PRINT ''
    SET @tmpstr = '-- Login: ' + @name
    PRINT @tmpstr
    IF (@type IN ( 'G', 'U'))
    BEGIN -- NT authenticated account/group

      SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE = [' + @defaultdb + ']'
    END
    ELSE BEGIN -- SQL Server authentication
        -- obtain password and sid
            SET @PWD_varbinary = CAST( LOGINPROPERTY( @name, 'PasswordHash' ) AS varbinary (256) )
        EXEC sp_hexadecimal @PWD_varbinary, @PWD_string OUT
        EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT

        -- obtain password policy state
        SELECT @is_policy_checked = CASE is_policy_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSENULL END FROM sys.sql_logins WHERE name = @name
        SELECT @is_expiration_checked = CASE is_expiration_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF'ELSE NULL END FROM sys.sql_logins WHERE name = @name

            SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' WITH PASSWORD = ' + @PWD_string+ ' HASHED, SID = ' + @SID_string + ', DEFAULT_DATABASE = [' + @defaultdb + ']'

        IF ( @is_policy_checked IS NOT NULL )
        BEGIN
          SET @tmpstr = @tmpstr + ', CHECK_POLICY = ' + @is_policy_checked
        END
        IF ( @is_expiration_checked IS NOT NULL )
        BEGIN
          SET @tmpstr = @tmpstr + ', CHECK_EXPIRATION = ' + @is_expiration_checked
        END
    END
    IF (@denylogin = 1)
    BEGIN -- login is denied access
      SET @tmpstr = @tmpstr + '; DENY CONNECT SQL TO ' + QUOTENAME( @name )
    END
    ELSE IF (@hasaccess = 0)
    BEGIN -- login exists but does not have access
      SET @tmpstr = @tmpstr + '; REVOKE CONNECT SQL TO ' + QUOTENAME( @name )
    END
    IF (@is_disabled = 1)
    BEGIN -- login is disabled
      SET @tmpstr = @tmpstr + '; ALTER LOGIN ' + QUOTENAME( @name ) + ' DISABLE'
    END
    PRINT @tmpstr
  END

  FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb,@hasaccess, @denylogin
   END
CLOSE login_curs
DEALLOCATE login_curs
RETURN 0
GO

·         Note This script creates two stored procedures in the master database. The two stored procedures are named thesp_hexadecimal stored procedure and the sp_help_revlogin stored procedure.


·         Run the following statement.
EXEC sp_help_revlogin
·         The output script that is generated by the sp_help_revlogin stored procedure is the login script. This login script creates the logins that have the original Security Identifier (SID) and the original password.


  
    Failover:

·         Before Disabling Log shipping jobs please Copy any uncopied backup files from the Shared Folder on Primary server to the Shared destination folder on secondary server by using copy job.

·         Check all the Transaction log has been successfully applied on the secondary server, if not please run the Restore Job to apply unapplied transaction log backups on secondary server.


             Disable Log Shipping Jobs:


·         Disable Log shipping jobs on Primary Server (bhamare3).


·         Disable Log shipping jobs on Secondary Server (bhamare3\Named).





       T-Log Backup:

  • Kill the sessions open for the DB on which you have to take Tail log backup.
  • Manually perform a tail-log backup of the transaction log on the primary database specifying leave database in Restoring State. This log backup captures any log records that have not been backed up yet and takes the database in Restoring state. The following example creates a tail log backup of the ‘AdventureWorks2008’ database on the primary server.
  • We recommend that you use a distinct file naming convention to differentiate the manually-created backup file from the backup files created by the log shipping backup job.




·         Select Backup tail log and leave database in restoring state option.



·         DB on primary Server (bhamare3) will go in restoring state.
             Restore T-Log Backup:

·         Now restore the tlog backup on Secondary Server(bhamare3\Named).




·         The database on secondary server (bhamare3\Named) will come in online state.


·         Check all the transactions are happening correctly.

        Log Shipping Configuration:


·         Now configure log shipping on Secondary Server (bhamare3\Named) DB.









       Failback:

           Run Log shipping jobs:


·         Run the log shipping jobs on the primary server(bhamare3\Named).






           Log shipping Sync:

·         Check the log shipping is in sync by executing following query on Secondary Server (bhamare3).

select secondary_database,last_copied_file,last_restored_file from msdb..log_shipping_monitor_secondary




·         You can generate the log shipping sync report on Secondary Server (bhamare3)by

Right click on Instance Name > Reports > Standard Reports > Transaction Log shipping status




             T-Log Backup:

  • Kill the sessions open for the DB on which you have to take Tail log backup.
  • Manually perform a tail-log backup of the transaction log on the primary database specifying leave database in Restoring State. This log backup captures any log records that have not been backed up yet and takes the database in Restoring state. The following example creates a tail log backup of the ‘AdventureWorks2008’ database on the primary server.
  • We recommend that you use a distinct file naming convention to differentiate the manually-created backup file from the backup files created by the log shipping backup job.



·         Select Backup tail log and leave database in restoring state option.





            Disable Log shipping jobs:

·         Disable the Log shipping job on Primary Server (bhamare3\Named).


·         Before Disabling Log shipping jobs please Copy any uncopied backup files from the Shared Folder on Primary server to the Shared destination folder on secondary server by using copy job.

·         Check all the Transaction log has been successfully applied on the secondary server, if not please run the Restore Job to apply unapplied transaction log backups on secondary server.






            Restore T-Log Backup:


·         Now restore the tlog backup on Secondary Server (bhamare3).






·         The DB on Secondary server (bhamare3) will go in restoring state.




·         Now enable the Log shipping jobs on Secondary server (bhamare3).






·         Start / Run Log shipping Jobs on secondary server (bhamare3).






·         The DB on primary Server (bhamare3\Named) will go in Stand by state means this server will become secondary server.
              Log Shipping Sync:

·         Check the log shipping is in sync by executing following query on Secondary Server(bhamare3\Named).

select secondary_database,last_copied_file,last_restored_file from msdb..log_shipping_monitor_secondary




·         You can generate the log shipping sync report on Secondary Server (bhamare3\Named) by Right click on Instance Name > Reports > Standard Reports > Transaction Log shipping status



No comments:

Post a Comment

COMMON SQL SERVER BACKUP FAILURE ERRORS AND ISSUES

  One of the most common task for a DBA’s are to perform installation of new SQL Server versions and installing patches. Most often or not e...