본문 바로가기

SQL/도움말 팁들!

Sql Server 2000 에서 사용자 로그인계정 정보 가져오는 SP - sp_help_revlogin


A blog on Australia's leading SQL Server consultants, trainers and Business Intelligence specialists

sp_help_revlogin - 'LOGINPROPERTY' is not a recognized function name.
sp_help_revlogin - 'LOGINPROPERTY'  인식할 수 없는 함수명입니다.

The Microsoft Knowledge Base Article 246133 - How to transfer logins and passwords between instances of SQL Server details how to create the Stored Procedure sp_help_revlogin.  This stored procedure is used to transfer logins from one SQL Server instance to another.  However the latest revision of this article has been modified for SQL Server 2005 and is unable to be run on SQL Sever 2000 without modification.
The Microsoft Knowledge Base Article 246133 - SQL Server 인스턴스 사이에 로그인계정과 비밀번호들을 어떻게 보낼 수 있을까? SP sp_help_revlogin 를 어떻게 만들 수 있을까? 이 프로시저는 하나의 SQL Server 인스턴스에서 다른 하나로 로그인 정보들을 보내는데 사용된다. 하지만 이 글의 최신버전은 SQL Server 2005 용으로 수정되었고, 이는 SQL Server 2000에는 수정 하지 않고서는 사용할 수 없다.
 
When the code in the article is run to create the sp_help_revlogin Stored Procedure on SQL Server 2000 the following error occurs:
sp_help_revlogin를 생성하기 위해 이 글에 있는 코드를 SQL Server 2000 에서 실행하면 아래와 같은 에러가 발생한다 :

Server: Msg 195, Level 15, State 10, Procedure sp_help_revlogin, Line 52
'LOGINPROPERTY' is not a recognized function name.
'LOGINPROPERTY' 는 인식할 수 없는 함수명입니다.
 
Below is a copy of the code for sp_help_revlogin Stored Procedure that will execute on SQL server 2000.  This code is from an archived version of the Knowledge Base Article.
 아래는  SQL server 2000에서 실행될 sp_help_revlogin 저장프로시저 코드의 사본입니다. 이 코드는 Knowledge Base Article 의 아카이브 버전에서 가져온 것입니다.


SQL Server 2000용

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 @xstatus int

DECLARE @binpwd  varbinary (256)

DECLARE @txtpwd  sysname

DECLARE @tmpstr  varchar (256)

DECLARE @SID_varbinary varbinary(85)

DECLARE @SID_string varchar(256)

 

IF (@login_name IS NULL)

  DECLARE login_curs CURSOR FOR

    SELECT sid, name, xstatus, password FROM master..sysxlogins

    WHERE srvid IS NULL AND name <> 'sa'

ELSE

  DECLARE login_curs CURSOR FOR

    SELECT sid, name, xstatus, password FROM master..sysxlogins

    WHERE srvid IS NULL AND name = @login_name

OPEN login_curs

FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @xstatus, @binpwd

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 ''

PRINT 'DECLARE @pwd sysname'

WHILE (@@fetch_status <> -1)

BEGIN

  IF (@@fetch_status <> -2)

  BEGIN

    PRINT ''

    SET @tmpstr = '-- Login: ' + @name

    PRINT @tmpstr

    IF (@xstatus & 4) = 4

    BEGIN -- NT authenticated account/group

      IF (@xstatus & 1) = 1

      BEGIN -- NT login is denied access

        SET @tmpstr = 'EXEC master..sp_denylogin ''' + @name + ''''

        PRINT @tmpstr

      END

      ELSE BEGIN -- NT login has access

        SET @tmpstr = 'EXEC master..sp_grantlogin ''' + @name + ''''

        PRINT @tmpstr

      END

    END

    ELSE BEGIN -- SQL Server authentication

      IF (@binpwd IS NOT NULL)

      BEGIN -- Non-null password

        EXEC sp_hexadecimal @binpwd, @txtpwd OUT

        IF (@xstatus & 2048) = 2048

          SET @tmpstr = 'SET @pwd = CONVERT (varchar(256), ' + @txtpwd + ')'

        ELSE

          SET @tmpstr = 'SET @pwd = CONVERT (varbinary(256), ' + @txtpwd + ')'

        PRINT @tmpstr

 EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT

        SET @tmpstr = 'EXEC master..sp_addlogin ''' + @name

          + ''', @pwd, @sid = ' + @SID_string + ', @encryptopt = '

      END

      ELSE BEGIN

        -- Null password

 EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT

        SET @tmpstr = 'EXEC master..sp_addlogin ''' + @name

          + ''', NULL, @sid = ' + @SID_string + ', @encryptopt = '

      END

      IF (@xstatus & 2048) = 2048

        -- login upgraded from 6.5

        SET @tmpstr = @tmpstr + '''skip_encryption_old'''

      ELSE

        SET @tmpstr = @tmpstr + '''skip_encryption'''

      PRINT @tmpstr

    END

  END

  FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @xstatus, @binpwd

  END

CLOSE login_curs

DEALLOCATE login_curs

RETURN 0

GO



SQL Server 2005 용

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)

 

IF (@login_name IS NULL)

        DECLARE login_curs CURSOR FOR

                       SELECT p.sid, p.name, p.type, p.is_disabled, 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, 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, @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'

               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

 

                              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 has 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, @hasaccess, @denylogin

        END

CLOSE login_curs

DEALLOCATE login_curs

 

RETURN 0

GO