Muokkaa

Jaa


Troubleshoot orphaned users (SQL Server)

Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW)

Orphaned users in SQL Server occur when a database user is based on a login in the master database, but the login no longer exists in master. This can occur when the login is deleted, or when the database is moved to another server where the login does not exist. This topic describes how to find orphaned users, and remap them to logins.

Note

Reduce the possibility of orphaned users by using contained database users for databases that might be moved. For more information, see Contained Database Users - Making Your Database Portable.

Background

To connect to a database on an instance of SQL Server using a security principal (database user identity) based on a login, the principal must have a valid login in the master database. This login is used in the authentication process that verifies the principals identity and determines if the principal is allowed to connect to the instance of SQL Server. The SQL Server logins on a server instance are visible in the sys.server_principals catalog view and the sys.sql_logins compatibility view.

SQL Server logins access individual databases as "database user" that is mapped to the SQL Server login. There are three exceptions to this rule:

  • Contained database users

    Contained database users authenticate at the user-database level and are not associated with logins. This is recommended because the databases are more portable and contained database users cannot become orphaned. However they must be recreated for each database. This might be impractical in an environment with many databases.

  • The guest account.

    When enabled in the database, this account permits SQL Server logins that are not mapped to a database user to enter the database as the guest user. The guest account is disabled by default.

  • Microsoft Windows group memberships.

    A SQL Server login created from a Windows user can enter a database if the Windows user is a member of a Windows group that is also a user in the database.

Information about the mapping of a SQL Server login to a database user is stored within the database. It includes the name of the database user and the SID of the corresponding SQL Server login. The permissions of this database user are applied for authorization in the database.

A database user (based on a login) for which the corresponding SQL Server login is undefined or is incorrectly defined on a server instance cannot log in to the instance. Such a user is said to be an orphaned user of the database on that server instance. Orphaning can happen if the database user is mapped to a login SID that is not present in the master instance. A database user can become orphaned after a database is restored or attached to a different instance of SQL Server where the login was never created. A database user can also become orphaned if the corresponding SQL Server login is dropped. Even if the login is recreated, it will have a different SID, so the database user will still be orphaned.

Detect Orphaned Users

For SQL Server and PDW

To detect orphaned users in SQL Server based on missing SQL Server authentication logins, execute the following statement in the user database:

SELECT dp.type_desc, dp.sid, dp.name AS user_name  
FROM sys.database_principals AS dp  
LEFT JOIN sys.server_principals AS sp  
    ON dp.sid = sp.sid  
WHERE sp.sid IS NULL  
    AND dp.authentication_type_desc = 'INSTANCE';  

The output lists the SQL Server authentication users and corresponding security identifiers (SID) in the current database that are not linked to any SQL Server login.

For SQL Database and Azure Synapse Analytics

The sys.server_principals table is not available in SQL Database or Azure Synapse Analytics. Identify orphaned users in those environments with the following steps:

  1. Connect to the master database and select the SID's for the logins with the following query:

    SELECT sid 
    FROM sys.sql_logins 
    WHERE type = 'S'; 
    
  2. Connect to the user database and review the SID's of the users in the sys.database_principals table, by using the following query:

    SELECT name, sid, principal_id
    FROM sys.database_principals 
    WHERE type = 'S' 
      AND name NOT IN ('guest', 'INFORMATION_SCHEMA', 'sys')
      AND authentication_type_desc = 'INSTANCE';
    
  3. Compare the two lists to determine if there are user SID's in the user database sys.database_principals table which are not matched by login SID's in the master database sql_logins table.

Resolve an Orphaned User

In the master database, use the CREATE LOGIN statement with the SID option to recreate a missing login, providing the SID of the database user obtained in the previous section:

CREATE LOGIN <login_name>   
WITH PASSWORD = '<use_a_strong_password_here>',  
SID = <SID>;  

To map an orphaned user to a login which already exists in master, execute the ALTER USER statement in the user database, specifying the login name.

ALTER USER <user_name> WITH Login = <login_name>;  

When you recreate a missing login, the user can access the database using the password provided. Then the user can alter the password of the login account by using the ALTER LOGIN statement.

ALTER LOGIN <login_name> WITH PASSWORD = '<enterStrongPasswordHere>';  

Important

Any login can change its own password. Only logins with the ALTER ANY LOGIN permission can change the password of another user's login. However, only members of the sysadmin role can modify passwords of sysadmin role members.

See Also

CREATE LOGIN (Transact-SQL)
ALTER USER (Transact-SQL)
CREATE USER (Transact-SQL)
sys.database_principals (Transact-SQL)
sys.server_principals (Transact-SQL)
sp_change_users_login (Transact-SQL)
sp_addlogin (Transact-SQL)
sp_grantlogin (Transact-SQL)
sp_password (Transact-SQL)
sys.sysusers (Transact-SQL)
sys.sql_logins sys.syslogins (Transact-SQL)