Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2000 Forums
 SQL Server Administration (2000)
 please solv this query

Author  Topic 

Madhav
Starting Member

38 Posts

Posted - 2007-06-08 : 01:49:07
Dear forum members, please solve this problem

I had 2 database servers 'srv1', 'srv2'
In 'srv1' I had 'db1' database
---
first create a user called 'db1usr1' with read and write previlages only(not dbowner)

then take backup of 'db1' as 'db1bakup'
then u hav to restore the 'db1bakup' in srv2 as 'db2'
then u have 2 login in the 'srv2' machine as 'db1usr1'

here is the problem : it is('db1usr1') not logged in srv2 machine

you should login from the srv2 machine's qurey analyser with user name 'db1usr1'. you should not delete the user 'db1usr1' of 'db2' database and recreate the user. and also u ahould have the read, write permissions only to the 'db1usr1' user of the database 'db2'.

i think u understood the problem.....
please help me......

rmiao
Master Smack Fu Yak Hacker

7266 Posts

Posted - 2007-06-08 : 01:53:42
You need create sql login for db1usr1 on srv2 and map it to db user in db2 with sp_change_users_login.
Go to Top of Page

Madhav
Starting Member

38 Posts

Posted - 2007-06-08 : 01:57:47
quote:
Originally posted by rmiao

You need create sql login for db1usr1 on srv2 and map it to db user in db2 with sp_change_users_login.



can i use sp_change_users_login from srv2 machine's query analyser?..
Go to Top of Page

donpolix
Yak Posting Veteran

97 Posts

Posted - 2007-06-08 : 02:11:55
Another way also is to look at the SID of the sql login in srv1. Then recreate the login in srv2 using sp_addlogin and using @SID from srv1.

- Donn Policarpio
Go to Top of Page

Madhav
Starting Member

38 Posts

Posted - 2007-06-08 : 02:55:03
quote:
Originally posted by donpolix

Another way also is to look at the SID of the sql login in srv1. Then recreate the login in srv2 using sp_addlogin and using @SID from srv1.

- Donn Policarpio




it is not working.....
i used the following statement....executed from srv2 machine , logged in as 'sa'

EXEC sp_addlogin 'db1usr1', 0x59BDF3BC20D1974C8C913BE0AE360C87

i got the message....'new login created'...but unable to login from the query analyser in srv2 machine...using the login...'db1usr1'
Go to Top of Page

Madhav
Starting Member

38 Posts

Posted - 2007-06-08 : 03:28:53
quote:
Originally posted by donpolix

Another way also is to look at the SID of the sql login in srv1. Then recreate the login in srv2 using sp_addlogin and using @SID from srv1.

- Donn Policarpio



thanx Donn Policarpio, it is working fine....but if i had 100 users before taking backup...when i restore the database in srv2 ...hw can i fix all the users...in srv2 machine..? shall i use the same @SID procedure for all the 100 users or is there any other procedure....?
please help me.......
Go to Top of Page

TonyTheDBA
Posting Yak Master

121 Posts

Posted - 2007-06-08 : 09:12:25
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 master
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

CREATE 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'
END
ELSE
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
END
OPEN 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
END
SELECT @tmpstr = '/* sp_help_revlogin script '
PRINT @tmpstr
SELECT @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
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,
@dbname
END
CLOSE login_curs
DEALLOCATE login_curs
RETURN 0

GO



--
Regards
Tony The DBA
Go to Top of Page
   

- Advertisement -