Category Archives: Disaster Recovery

sp_help_revlogin revisited

I believe I’ve come up with an improvement to sp_help_revlogin.

Transferring a login from one server to another is one of those learning experiences we all go through. If you just do CREATE LOGIN on another server the login in the master database usually gets a different ID. When you restore the database on the other server, the ID of the user in the database doesn’t match the ID of the login in master and so the login can’t access the database. (And, as they say, ‘hilarity ensues’.)

A better way to move the login is to use a Microsoft stored procedure sp_help_revlogin (read more here: http://support.microsoft.com/kb/918992/) to generate a script that will re-create the login with the same ID. But I noticed it doesn’t include the login’s default language, which is something that can have a major impact on things like whether the account can re-use existing cached query plans. So I’ve added this element.

Instead of this:

CREATE LOGIN [loginX]
WITH	PASSWORD = 0x02<snip>9E HASHED
	, SID = 0x8E<snip>80
	, DEFAULT_DATABASE = [databaseY]
	, CHECK_POLICY = ON
	, CHECK_EXPIRATION = OFF

you now get this:

create login [loginX]
with	password = 0x02<snip>9E hashed
	, sid = 0x8E<snip>80
	, default_database = [databaseY]
	, default_language = [us_english]
	, check_policy = on
	, check_expiration = off

(While I was at it, I changed the output to lower case because that’s how I like to code.)

Here’s the new version of the procedure with the altered lines highlighted:

/*
Purpose:	To script out logins for copying to another server.
Source:		http://support.microsoft.com/kb/918992/
Modifications:	I added the default language.
*/

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 &amp;amp;lt;= @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
DECLARE @defaultlanguage 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, p.default_language_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 &amp;amp;lt;&amp;amp;gt; 'sa'
ELSE
  DECLARE login_curs CURSOR FOR

      SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, p.default_language_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, @defaultlanguage, @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 &amp;amp;lt;&amp;amp;gt; -1)
BEGIN
  IF (@@fetch_status &amp;amp;lt;&amp;amp;gt; -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 + '], default_language = [' + @defaultlanguage + ']'
    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' ELSE NULL 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 + '], default_language = [' + @defaultlanguage + ']'

        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, @defaultlanguage, @hasaccess, @denylogin
   END
CLOSE login_curs
DEALLOCATE login_curs
RETURN 0
GO

You can download the code here.

Something to check for on your Disaster Recovery plan

We just had something happen that caught us by surprise. We were log shipping to a remote warm standby server. It was all running smoothly and we were ready for anything. Then the remote server went down – right down. Looks like we might have to rebuild it. Meanwhile, I’ve got transaction log backups piling up and nowhere to ship them to. Without a standby server that’s on the same backup cycle as the live server we just don’t have a DR plan that applies. Now I have to tell people I can’t do those urgent things I promised to deliver because I have to sort this out. And I thought it was hard enough getting buy-in for setting this up in the first place!

When we drew up our plan we did briefly consider what would happen in this scenario. We were far too casual. We said to ourselves, “Well, we didn’t have this capability at all until now and we’ve never had a disaster so it won’t be such a problem to be without it again while we fix it. After all, you can only plan for so much and after that you just have to wing it.” Wrong answer! The last thing you want to be doing when things are all screwed up is to start improvising. A standby server is just as likely to fail as a live server, maybe even more likely. After all, you keep a keen pro-active eye on your live servers – you are doing that, right? – but it’s hard to justify spending too much time monitoring a standby server. As long as the replication/mirroring/log-shipping works, that’s fine. Wrong! A standby server is just as important and warrants just as much care and feeding.

Don’t let this happen to you. What does your plan say about the standby going down? How does it affect your routine DR jobs etc. How will you get a standby server back again? Do you need to alert the business that you may need some budget? How will you re-synch it with your live server so you can resume normal operations again? Knowing in principle is not enough. Write it down. Test it. Know it will work.