Fixing Orphaned Users

  • Comments posted to this topic are about the item Fixing Orphaned Users

    - Tim Ford, SQL Server MVPhttp://www.sqlcruise.comhttp://www.thesqlagentman.com http://www.linkedin.com/in/timothyford

  • 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.

  • 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.

  • 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!

  • 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. 🙂

    ATBCharles Kincaid

  • 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.

  • What is the difference between Auto_Fix and Update_One?

    ThomasLL

    Thomas LeBlanc, MVP Data Platform Consultant

  • 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.

  • 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 MVPhttp://www.sqlcruise.comhttp://www.thesqlagentman.com http://www.linkedin.com/in/timothyford

  • 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

  • Nice article:)

    I It's mentioned that orphaned users do no exist in Windows logins, This is true for the same domain, but if you restore the database to another domain, I believe it's not.

Viewing 11 posts - 1 through 10 (of 10 total)

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