How to Copy/Export SQL Group Connections between Server

  • Hi,

    I need to know how to copy/export Sql Server

    group connections between servers

     

    Thanks a lot

     

  • Script to Create sp_hexidecimal and sp_help_revlogin

    ----------------------------------------------------

    Create and Run Stored Procedures in the Master Database

    Review the remarks at the end of this article for important information about the following steps.

    1. Run the following script on the source SQL Server. This script creates two stored procedures named sp_hexadecimal and sp_help_revlogin in your master database. Continue to step 2 when you finish creating the procedure.

    Note The following procedure is dependent on SQL Server system tables. The structure of these tables may change between versions of SQL Server, and selecting directly from system tables is discouraged.

    ----- Begin Script, Create sp_help_revlogin procedure -----

    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(256) OUTPUT

    AS

    DECLARE @charvalue varchar(256)

    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

    ----- End Script -----

    2. After you create the sp_help_revlogin stored procedure, run the sp_help_revlogin procedure from Query Analyzer on the source server. The sp_help_revlogin stored procedure can be used on both SQL Server 7.0 and SQL Server 2000. The output of the sp_help_revlogin stored procedure is login scripts that create logins with the original SID and password. Save the output, and then paste and run it in Query Analyzer on the destination SQL Server. For example:

    EXEC master..sp_help_revlogin

    • Review the output script carefully before you run it on the destination SQL Server. If you have to transfer logins to an instance of SQL Server in a different domain than the source instance of SQL Server, edit the script generated by the sp_help_revlogin procedure, and replace the domain name with the new domain in the sp_grantlogin statements. Because the integrated logins granted access in the new domain will not have the same SID as the logins in the original domain, the database users will be orphaned from these logins. To resolve these orphaned users, see the articles referenced in the following bullet item. If you transfer integrated logins between instances of SQL Servers in the same domain, the same SID is used and the user is not likely to be orphaned.

    • After you move the logins, users may not have permissions to access databases that have also been moved. This problem is described as an "orphaned user". If you try to grant the login access to the database, it may fail indicating the user already exists:

    Microsoft SQL-DMO (ODBC SQLState: 42000) Error 15023: User or role '%s' already exists in the current database.

    For instructions about how to map the logins to the database users to resolve orphaned SQL Server logins and integrated logins, see the following article in the Microsoft Knowledge Base:

    240872 HOW TO: Resolve Permission Issues When You Move a Database Between Servers That Are Running SQL Server

    For instructions about using the sp_change_users_login stored procedure to correct the orphaned users one-by-one (this will only address users orphaned from standard SQL logins), see the following article in the Microsoft Knowledge Base:

    274188 PRB: "Troubleshooting Orphaned Users" Topic in Books Online is Incomplete

    • If the transfer of logins and passwords is part of a move of databases to a new server running SQL Server, see the following article in the Microsoft Knowledge Base for a description of the workflow and steps involved:

    314546 HOW TO: Move Databases Between Computers That Are Running SQL Server

    • You can do this because of the @encryptopt parameter in the sp_addlogin system stored procedure, that allows a login to be created by using the encrypted password. For more information about this procedure, see the "sp_addlogin (T-SQL)" topic in SQL Server Books Online.

    • By default, only members of the sysadminfixed server role can select from the sysxlogins table. Unless a member of the sysadmin role grants the necessary permissions, end users cannot create or run these stored procedures.

    • This approach does not try to transfer the default database information for a particular login because the default database may not always exist on the destination server. To define the default database for a login, you can use the sp_defaultdb system stored procedure by passing it the login name and the default database as arguments. For more information about using this procedure, see the "sp_defaultdb" topic in SQL Server Books Online.

    • During a transfer of logins between instances of SQL Server, if the sort order of the source server is case-insensitive and the sort order of the destination server is case-sensitive, you must enter all alphabetical characters in passwords as uppercase characters after the transfer of logins to the destination server.If the sort order of the source server is case-sensitive and the sort order of the destination server is case-insensitive, you will not be able to log in with the logins transferred using the procedure outlined in this article, unless the original password contains no alphabetical characters or unless all alphabetical characters in the original password are uppercase characters. If both servers are case-sensitive or both servers are case-insensitive, you will not experience this problem. This is a side effect of the way that SQL Server handles passwords. For more information, see the "Effect on Passwords of Changing Sort Orders" topic in SQL Server 7.0 Books Online.

    • When you run the output from the sp_help_revlogin script on a server, if the server already has a login defined with the same name as one of the logins on the script output, you may see the following error upon execution of the output of the sp_help_revlogin script:

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply