This Isn't My Work, I'm sure I found thes scripts here, but can't remember from where. I would like to credit the original authors, but the only thing I can say is that these scripts work really well so thank you very much. If you need to move all the users just execute sp_rev_login without a parameter and it scripts the logins for you. You then execute that script on the other server.USE masterGOCREATE PROCEDURE sp_hexadecimal @binvalue varbinary(256), @hexvalue varchar(256) OUTPUTASDECLARE @charvalue varchar(256)DECLARE @i intDECLARE @length intDECLARE @hexstring char(16)SELECT @charvalue = '0x'SELECT @i = 1SELECT @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 + 1ENDSELECT @hexvalue = @charvalueGOCREATE PROCEDURE sp_help_revlogin @login_name sysname = NULL AS--Declare needed variables.DECLARE @name sysname, @xstatus int, @binpwd varbinary (256), @txtpwd sysname, @tmpstr varchar (256), @SID_varbinary varbinary(85), @SID_string varchar(256), @dbname varchar(255)--Determine whether to process one login or all. Set up cursor accordingly.IF (@login_name IS NULL) BEGIN DECLARE login_curs CURSOR FOR SELECT sxl.sid, sxl.name, sxl.xstatus, sxl.password, sd.name AS dbname FROM master..sysxlogins sxl INNER JOIN master..sysdatabases sd ON sxl.dbid = sd.dbid WHERE sxl.srvid IS NULL AND sxl.name <> 'sa' ENDELSE BEGIN DECLARE login_curs CURSOR FOR SELECT sxl.sid, sxl.name, sxl.xstatus, sxl.password, sd.name AS dbname FROM master..sysxlogins sxl INNER JOIN master..sysdatabases sd ON sxl.dbid = sd.dbid WHERE sxl.srvid IS NULL AND sxl.name <> @login_name ENDOPEN login_curs FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @xstatus, @binpwd, @dbname--If no logins found, exit the procedure.IF (@@fetch_status = -1) BEGIN PRINT 'No login(s) found.' CLOSE login_curs DEALLOCATE login_curs RETURN -1 ENDSELECT @tmpstr = '/* sp_help_revlogin script ' PRINT @tmpstrSELECT @tmpstr = '** Generated ' + CONVERT (varchar, GETDATE()) + ' on ' + @@SERVERNAME + ' */'PRINT @tmpstrPRINT ''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 BEGIN SET @tmpstr = 'SET @pwd = CONVERT (varchar(256), ' + @txtpwd + ')' END ELSE BEGIN SET @tmpstr = 'SET @pwd = CONVERT (varbinary(256), ' + @txtpwd + ')' END 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 BEGIN -- Null password EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT SET @tmpstr = 'EXEC master..sp_addlogin ''' + @name + ''', NULL, @sid = ' + @SID_string + ', @encryptopt = ' END END IF (@xstatus & 2048) = 2048 BEGIN -- login upgraded from 6.5 SET @tmpstr = @tmpstr + '''skip_encryption_old''' PRINT @tmpstr END ELSE BEGIN SET @tmpstr = @tmpstr + '''skip_encryption''' PRINT @tmpstr END END --Add the default database. SET @tmpstr = 'EXEC master..sp_defaultdb ''' + @name + ''',''' + @dbname + '''' PRINT @tmpstr END FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @xstatus, @binpwd, @dbnameENDCLOSE login_curs DEALLOCATE login_curs RETURN 0GO
-- RegardsTony The DBA