Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Fixing Orphaned Users Expand / Collapse
Author
Message
Posted Monday, December 03, 2007 9:27 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, March 25, 2014 7:55 AM
Points: 1,012, Visits: 440
Comments posted to this topic are about the item Fixing Orphaned Users

- Tim Ford, SQL Server MVP
http://www.sqlcruise.com
http://www.thesqlagentman.com
http://www.linkedin.com/in/timothyford
Post #429094
Posted Monday, December 03, 2007 9:35 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 9:21 PM
Points: 2,842, Visits: 2,423
I agree that this can be an issue but you can help yourself out a little by reviewing the syntax of the "CREATE LOGIN" or "sp_addlogin" commands.

Both of these commands allow you to specify the SID. If you are able to specify the same SID for the logins on each of the servers, you can happily backup/restore databases between instances and the login and user entries will match because you created the login on each instance with the same SID.

This is especially important when you are using log shipping or database mirroring. When a problem occurs and your primary server dies, there is one less issue that needs to be handled to get your standby database online. In the case of mirroring, ensuring that you use the same SID allows you to automatically bring the mirroring online with no intervention required.



Post #429095
Posted Tuesday, December 04, 2007 6:54 AM
SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: Moderators
Last Login: Today @ 11:14 AM
Points: 6,705, Visits: 1,679
I agree that sync'ing SID's is a pretty good idea. MS also has a script up on MSDN that will script out all your logins along with the encrypted passwords so you can just run it against the other server and be done.


Andy
SQLAndy - My Blog!
Connect with me on LinkedIn
Follow me on Twitter
Post #429260
Posted Tuesday, December 04, 2007 7:45 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: Administrators
Last Login: Today @ 4:56 PM
Points: 32,771, Visits: 14,935
sp_helprevlogin is the procedure, but it's a 2005 one only now. They updated it. The original for 7/2000 is available in the script library here.

http://www.sqlservercentral.com/scripts/Maintenance+and+Management/31711/

Nice article, Tim!







Follow me on Twitter: @way0utwest

Forum Etiquette: How to post data/code on a forum to get the best help
Post #429308
Posted Tuesday, December 04, 2007 9:57 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Thursday, February 06, 2014 12:59 PM
Points: 801, Visits: 1,962
Great article Tim. Thanks. You said:
You can add the login to the SQL instance and re-run the script thereby reconciling the user and login.
Since you are discussing moving from test to production would it not be better to scan for missing logins and removed those users by default? The thinking is more restriction is better so if the login does not exist on the server you can't grant permissions.

I have the same challenge in the opposite direction. I pull production databases and restore to our development servers. I had this problem in SQL 2000 but I found an odd work-around. If I stop and restart the service SQL seems to relink my logins by itself. :)


ATB

Charles Kincaid

Post #429421
Posted Tuesday, December 04, 2007 10:33 AM
SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: Moderators
Last Login: Today @ 3:54 PM
Points: 8,369, Visits: 733
This is what I personally use

select 'exec sp_change_users_login ''AUTO_FIX'',''' + [name] + '''', * from sysusers where status != 0 and uid > 2

it builds a string for each account, then I take and run the resultset in another window.



Post #429441
Posted Tuesday, December 04, 2007 3:43 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Monday, April 14, 2014 10:01 AM
Points: 2,979, Visits: 762
What is the difference between Auto_Fix and Update_One?

ThomasLL


Thomas LeBlanc, MCITP DBA 2005, 2008 & MCDBA 2000
http://thesmilingdba.blogspot.com/
Post #429560
Posted Wednesday, December 05, 2007 7:35 AM
SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: Moderators
Last Login: Today @ 3:54 PM
Points: 8,369, Visits: 733
ThomasLL (12/4/2007)
What is the difference between Auto_Fix and Update_One?

ThomasLL


AUTO_FIX matches based on the user alias in the DB to a login account.

UPDATE_ONE allows you to specify the alias mapping to the login account.

See BOL for more detail if needs be.



Post #429773
Posted Wednesday, December 05, 2007 8:05 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, March 25, 2014 7:55 AM
Points: 1,012, Visits: 440
I used to use sp_update_user_logins all the time, but with 80+ servers and almost 1,000 databases that I support without aid of a Jr. DBA I had to abandon that for something more automated and global across multiple logins at one time. It is a great stored proc though.

- Tim Ford, SQL Server MVP
http://www.sqlcruise.com
http://www.thesqlagentman.com
http://www.linkedin.com/in/timothyford
Post #429790
Posted Thursday, December 06, 2007 1:52 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Tuesday, January 28, 2014 2:51 PM
Points: 55, Visits: 249
I also have similar problem.
Step 1.
Create the file get_users_login.sql
select 'exec sp_change_users_login ' + quotename('Update_One', char(39)) + ',' + quotename(sl.name, char(39)) + ',' + quotename(su.name, char(39)) + ';'
from master.dbo.syslogins sl
join dbo.sysusers su on sl.sid = su.sid
where sl.hasaccess = 1
and sl.isntname = 0
and sl.name not in ('guest', 'dbo', 'sys', 'INFORMATION_SCHEMA')

Step 2.
osql get_users_login.sql -o fix_users_login.sql -w 2048 -n -h-1

Step 3.
Run osql fix_users_login.sql against any other server
Post #430424
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse