ALTER USER (Transact-SQL)
Renames a database user or changes its default schema.
Transact-SQL syntax conventions
Note
Microsoft Entra ID was previously known as Azure Active Directory (Azure AD).
Select a product
In the following row, select the product name you're interested in, and only that product's information is displayed.
* SQL Server *
SQL Server
Syntax
-- Syntax for SQL Server
ALTER USER userName
WITH <set_item> [ ,...n ]
[;]
<set_item> ::=
NAME = newUserName
| DEFAULT_SCHEMA = { schemaName | NULL }
| LOGIN = loginName
| PASSWORD = 'password' [ OLD_PASSWORD = 'oldpassword' ]
| DEFAULT_LANGUAGE = { NONE | <lcid> | <language name> | <language alias> }
| ALLOW_ENCRYPTED_VALUE_MODIFICATIONS = [ ON | OFF ]
Arguments
userName Specifies the name by which the user is identified inside this database.
LOGIN = loginName Remaps a user to another login by changing the user's Security Identifier (SID) to match the login's SID.
NAME = newUserName Specifies the new name for this user. newUserName must not already occur in the current database.
DEFAULT_SCHEMA = { schemaName | NULL } Specifies the first schema that will be searched by the server when it resolves the names of objects for this user. Setting the default schema to NULL removes a default schema from a Windows group. The NULL option cannot be used with a Windows user.
PASSWORD = 'password' Applies to: SQL Server 2012 (11.x) and later, SQL Database.
Specifies the password for the user that is being changed. Passwords are case-sensitive.
Note
This option is available only for contained users. For more information, see Contained Databases and sp_migrate_user_to_contained (Transact-SQL).
OLD_PASSWORD ='oldpassword' Applies to: SQL Server 2012 (11.x) and later, SQL Database.
The current user password that will be replaced by 'password'. Passwords are case-sensitive. OLD_PASSWORD is required to change a password, unless you have ALTER ANY USER permission. Requiring OLD_PASSWORD prevents users with IMPERSONATION permission from changing the password.
Note
This option is available only for contained users.
DEFAULT_LANGUAGE ={ NONE | <lcid> | <language name> | <language alias> } Applies to: SQL Server 2012 (11.x) and later.
Specifies a default language to be assigned to the user. If this option is set to NONE, the default language is set to the current default language of the database. If the default language of the database is later changed, the default language of the user will remain unchanged. DEFAULT_LANGUAGE can be the local ID (lcid), the name of the language, or the language alias.
Note
This option may only be specified in a contained database and only for contained users.
ALLOW_ENCRYPTED_VALUE_MODIFICATIONS = [ ON | OFF ] Applies to: SQL Server 2016 (13.x) and later, SQL Database.
Suppresses cryptographic metadata checks on the server in bulk copy operations. This enables the user to bulk copy encrypted data between tables or databases, without decrypting the data. The default is OFF.
Warning
Improper use of this option can lead to data corruption. For more information, see Migrate Sensitive Data Protected by Always Encrypted.
Remarks
The default schema will be the first schema that will be searched by the server when it resolves the names of objects for this database user. Unless otherwise specified, the default schema will be the owner of objects created by this database user.
If the user has a default schema, that default schema will be used. If the user doesn't have a default schema, but the user is a member of a group that has a default schema, the default schema of the group will be used. If the user doesn't have a default schema, and is a member of more than one group, the default schema for the user will be that of the Windows group with the lowest principal_id and an explicitly set default schema. If no default schema can be determined for a user, the dbo schema will be used.
DEFAULT_SCHEMA can be set to a schema that doesn't currently occur in the database. Therefore, you can assign a DEFAULT_SCHEMA to a user before that schema is created.
DEFAULT_SCHEMA can't be specified for a user who is mapped to a certificate, or an asymmetric key.
Important
The value of DEFAULT_SCHEMA is ignored if the user is a member of the sysadmin fixed server role. All members of the sysadmin fixed server role have a default schema of dbo
.
You can change the name of a user who is mapped to a Windows login or group only when the SID of the new user name matches the SID that is recorded in the database. This check helps prevent spoofing of Windows logins in the database.
The WITH LOGIN clause enables the remapping of a user to a different login. Users without a login, users mapped to a certificate, or users mapped to an asymmetric key can't be remapped with this clause. Only SQL users and Windows users (or groups) can be remapped. The WITH LOGIN clause can't be used to change the type of user, such as changing a Windows account to a SQL Server login.
A mismatched SID can occur when you have restored a database from another server and have a database user mapped to a SQL Server login. You can use the WITH LOGIN clause to correct this situation by replacing the user SID in the database with the login SID from the server.
The name of the user will be automatically renamed to the login name if the following conditions are true.
The user is a Windows user.
The name is a Windows name (contains a backslash).
No new name was specified.
The current name differs from the login name.
Otherwise, the user won't be renamed unless the caller additionally invokes the NAME clause.
The name of a user mapped to a SQL Server login, a certificate, or an asymmetric key can't contain the backslash character (\).
Caution
Beginning with SQL Server 2005, the behavior of schemas changed. As a result, code that assumes that schemas are equivalent to database users may no longer return correct results. Old catalog views, including sysobjects, should not be used in a database in which any of the following DDL statements have ever been used: CREATE SCHEMA, ALTER SCHEMA, DROP SCHEMA, CREATE USER, ALTER USER, DROP USER, CREATE ROLE, ALTER ROLE, DROP ROLE, CREATE APPROLE, ALTER APPROLE, DROP APPROLE, ALTER AUTHORIZATION. In such databases you must instead use the new catalog views. The new catalog views take into account the separation of principals and schemas that was introduced in SQL Server 2005. For more information about catalog views, see Catalog Views (Transact-SQL).
Security
Note
A user who has ALTER ANY USER permission can change the default schema of any user. A user who has an altered schema might unknowingly select data from the wrong table or execute code from the wrong schema.
Permissions
To change the name of a user requires the ALTER ANY USER permission.
To change the target login of a user requires the CONTROL permission on the database.
To change the user name of a user having CONTROL permission on the database requires the CONTROL permission on the database.
To change the default schema or language requires ALTER permission on the user. Users can change their own default schema or language.
Examples
All examples are executed in a user database.
A. Changing the name of a database user
The following example changes the name of the database user Mary5
to Mary51
.
ALTER USER Mary5 WITH NAME = Mary51;
GO
B. Changing the default schema of a user
The following example changes the default schema of the user Mary51
to Purchasing
.
ALTER USER Mary51 WITH DEFAULT_SCHEMA = Purchasing;
GO
C. Changing several options at once
The following example changes several options for a contained database user in one statement.
Applies to: SQL Server 2012 (11.x) and later.
ALTER USER Philip
WITH NAME = Philipe
, DEFAULT_SCHEMA = Development
, PASSWORD = 'W1r77TT98%ab@#' OLD_PASSWORD = 'New Devel0per'
, DEFAULT_LANGUAGE= French ;
GO
D. Correct a mismatched SID
The following example corrects the user SID in the database to match the SID on the server for a SQL Server authenticated login.
ALTER USER Mai
WITH LOGIN = Mai;
GO
See also
* Azure SQL Database and SQL Database in Fabric *
Azure SQL Database and SQL database in Microsoft Fabric
Syntax
Syntax for Azure SQL Database
-- Syntax for Azure SQL Database
ALTER USER userName
WITH <set_item> [ ,...n ]
<set_item> ::=
NAME = newUserName
| DEFAULT_SCHEMA = schemaName
| LOGIN = loginName
| ALLOW_ENCRYPTED_VALUE_MODIFICATIONS = [ ON | OFF ]
[;]
-- Azure SQL Database Update Syntax
ALTER USER userName
WITH <set_item> [ ,...n ]
[;]
<set_item> ::=
NAME = newUserName
| DEFAULT_SCHEMA = { schemaName | NULL }
| LOGIN = loginName
| PASSWORD = 'password' [ OLD_PASSWORD = 'oldpassword' ]
| ALLOW_ENCRYPTED_VALUE_MODIFICATIONS = [ ON | OFF ]
-- SQL Database syntax when connected to a federation member
ALTER USER userName
WITH <set_item> [ ,... n ]
[;]
<set_item> ::=
NAME = newUserName
Syntax for SQL database in Microsoft Fabric
ALTER USER
{
Microsoft_Entra_principal FROM EXTERNAL PROVIDER [WITH OBJECT_ID = 'objectid']
}
[ ; ]
-- Users that cannot authenticate
ALTER USER user_name
{
{ FOR | FROM } CERTIFICATE cert_name
| { FOR | FROM } ASYMMETRIC KEY asym_key_name
}
[ ; ]
<options_list> ::=
DEFAULT_LANGUAGE = { NONE | lcid | language name | language alias }
-- SQL Database syntax when connected to a federation member
ALTER USER user_name
[;]
Arguments
userName
Specifies the name by which the user is identified inside this database.
LOGIN = loginName
Remaps a user to another login by changing the user's Security Identifier (SID) to match the login's SID.
If the ALTER USER statement is the only statement in a SQL batch, Azure SQL Database supports the WITH LOGIN clause. If the ALTER USER statement isn't the only statement in a SQL batch or is executed in dynamic SQL, the WITH LOGIN clause isn't supported.
NAME = newUserName
Specifies the new name for this user. newUserName must not already occur in the current database.
DEFAULT_SCHEMA = { schemaName | NULL }
Specifies the first schema that will be searched by the server when it resolves the names of objects for this user. Setting the default schema to NULL removes a default schema from a Windows group. The NULL option can't be used with a Windows user.
PASSWORD = 'password'
Applies to: SQL Database.
Specifies the password for the user that is being changed. Passwords are case-sensitive.
Note
This option is available only for contained users. For more information, see Contained Databases and sp_migrate_user_to_contained (Transact-SQL).
OLD_PASSWORD ='oldpassword'
Applies to: SQL Database.
The current user password that will be replaced by 'password'. Passwords are case-sensitive. OLD_PASSWORD is required to change a password, unless you have ALTER ANY USER permission. Requiring OLD_PASSWORD prevents users with IMPERSONATION permission from changing the password.
Note
This option is available only for contained users.
ALLOW_ENCRYPTED_VALUE_MODIFICATIONS = [ ON | OFF ]
Applies to: SQL Server 2016 (13.x) and later, SQL Database.
Suppresses cryptographic metadata checks on the server in bulk copy operations. This enables the user to bulk copy encrypted data between tables or databases, without decrypting the data. The default is OFF.
Warning
Improper use of this option can lead to data corruption. For more information, see Migrate Sensitive Data Protected by Always Encrypted.
Remarks
The default schema will be the first schema that will be searched by the server when it resolves the names of objects for this database user. Unless otherwise specified, the default schema will be the owner of objects created by this database user.
If the user has a default schema, that default schema will used. If the user doesn't have a default schema, but the user is a member of a group that has a default schema, the default schema of the group will be used. If the user doesn't have a default schema, and is a member of more than one group, the default schema for the user will be that of the Windows group with the lowest principal_id and an explicitly set default schema. If no default schema can be determined for a user, the dbo schema will be used.
DEFAULT_SCHEMA can be set to a schema that doesn't currently occur in the database. Therefore, you can assign a DEFAULT_SCHEMA to a user before that schema is created.
DEFAULT_SCHEMA can't be specified for a user who is mapped to a certificate, or an asymmetric key.
Important
The value of DEFAULT_SCHEMA is ignored if the user is a member of the sysadmin fixed server role. All members of the sysadmin fixed server role have a default schema of dbo
.
You can change the name of a user who is mapped to a Windows login or group only when the SID of the new user name matches the SID that is recorded in the database. This check helps prevent spoofing of Windows logins in the database.
The WITH LOGIN clause enables the remapping of a user to a different login. Users without a login, users mapped to a certificate, or users mapped to an asymmetric key can't be remapped with this clause. Only SQL users and Windows users (or groups) can be remapped. The WITH LOGIN clause can't be used to change the type of user, such as changing a Windows account to a SQL Server login.
The name of the user will be automatically renamed to the login name if the following conditions are true.
The user is a Windows user.
The name is a Windows name (contains a backslash).
No new name was specified.
The current name differs from the login name.
Otherwise, the user won't be renamed unless the caller additionally invokes the NAME clause.
The name of a user mapped to a SQL Server login, a certificate, or an asymmetric key can't contain the backslash character (\).
Caution
Beginning with SQL Server 2005, the behavior of schemas changed. As a result, code that assumes that schemas are equivalent to database users may no longer return correct results. Old catalog views, including sysobjects, should not be used in a database in which any of the following DDL statements have ever been used: CREATE SCHEMA, ALTER SCHEMA, DROP SCHEMA, CREATE USER, ALTER USER, DROP USER, CREATE ROLE, ALTER ROLE, DROP ROLE, CREATE APPROLE, ALTER APPROLE, DROP APPROLE, ALTER AUTHORIZATION. In such databases you must instead use the new catalog views. The new catalog views take into account the separation of principals and schemas that was introduced in SQL Server 2005. For more information about catalog views, see Catalog Views (Transact-SQL).
Security
Note
A user who has ALTER ANY USER permission can change the default schema of any user. A user who has an altered schema might unknowingly select data from the wrong table or execute code from the wrong schema.
Permissions
To change the name of a user requires the ALTER ANY USER permission.
To change the target login of a user requires the CONTROL permission on the database.
To change the user name of a user having CONTROL permission on the database requires the CONTROL permission on the database.
To change the default schema or language requires ALTER permission on the user. Users can change their own default schema or language.
Examples
All examples are executed in a user database.
A. Changing the name of a database user
The following example changes the name of the database user Mary5
to Mary51
.
ALTER USER Mary5 WITH NAME = Mary51;
GO
B. Changing the default schema of a user
The following example changes the default schema of the user Mary51
to Purchasing
.
ALTER USER Mary51 WITH DEFAULT_SCHEMA = Purchasing;
GO
C. Changing several options at once
The following example changes several options for a contained database user in one statement.
ALTER USER Philip
WITH NAME = Philipe
, DEFAULT_SCHEMA = Development
, PASSWORD = 'W1r77TT98%ab@#' OLD_PASSWORD = 'New Devel0per';
GO
See also
* SQL Managed Instance *
Azure SQL Managed Instance
Syntax
Important
Only the following options are supported for Azure SQL Managed Instance when applying to users with Microsoft Entra logins:
DEFAULT_SCHEMA = { schemaName | NULL }
and
DEFAULT_LANGUAGE = { NONE | lcid | language name | language alias }
There is a new syntax extension that was added to help remap users in a database that was migrated to Azure SQL Managed Instance. The ALTER USER syntax helps map database users in a federated and synchronized domain with Microsoft Entra ID, to Microsoft Entra logins.
-- Syntax for SQL Managed Instance
ALTER USER userName
{ WITH <set_item> [ ,...n ] | FROM EXTERNAL PROVIDER }
[;]
<set_item> ::=
NAME = newUserName
| DEFAULT_SCHEMA = { schemaName | NULL }
| LOGIN = loginName
| PASSWORD = 'password' [ OLD_PASSWORD = 'oldpassword' ]
| DEFAULT_LANGUAGE = { NONE | <lcid> | <language name> | <language alias> }
| ALLOW_ENCRYPTED_VALUE_MODIFICATIONS = [ ON | OFF ]
-- Users or groups that are migrated as federated and synchronized with Azure AD have the following syntax:
/** Applies to Windows users that were migrated and have the following user names:
- Windows user <domain\user>
- Windows group <domain\MyWindowsGroup>
- Windows alias <MyWindowsAlias>
**/
ALTER USER userName
{ WITH <set_item> [ ,...n ] | FROM EXTERNAL PROVIDER }
[;]
<set_item> ::=
NAME = newUserName
| DEFAULT_SCHEMA = { schemaName | NULL }
| LOGIN = loginName
| DEFAULT_LANGUAGE = { NONE | <lcid> | <language name> | <language alias> }
Arguments
userName Specifies the name by which the user is identified inside this database.
LOGIN = loginName Remaps a user to another login by changing the user's Security Identifier (SID) to match the login's SID.
If the ALTER USER statement is the only statement in a SQL batch, Azure SQL Database supports the WITH LOGIN clause. If the ALTER USER statement isn't the only statement in a SQL batch or is executed in dynamic SQL, the WITH LOGIN clause isn't supported.
NAME = newUserName Specifies the new name for this user. newUserName must not already occur in the current database.
DEFAULT_SCHEMA = { schemaName | NULL } Specifies the first schema that will be searched by the server when it resolves the names of objects for this user. Setting the default schema to NULL removes a default schema from a Windows group. The NULL option can't be used with a Windows user.
PASSWORD = 'password'
Specifies the password for the user that is being changed. Passwords are case-sensitive.
Note
This option is available only for contained users. For more information, see Contained Databases and sp_migrate_user_to_contained (Transact-SQL).
OLD_PASSWORD = 'oldpassword'
The current user password that will be replaced by 'password'. Passwords are case-sensitive. OLD_PASSWORD is required to change a password, unless you have ALTER ANY USER permission. Requiring OLD_PASSWORD prevents users with IMPERSONATION permission from changing the password.
Note
This option is available only for contained users.
DEFAULT_LANGUAGE ={ NONE | <lcid> | <language name> | <language alias> }
Specifies a default language to be assigned to the user. If this option is set to NONE, the default language is set to the current default language of the database. If the default language of the database is later changed, the default language of the user will remain unchanged. DEFAULT_LANGUAGE can be the local ID (lcid), the name of the language, or the language alias.
Note
This option may only be specified in a contained database and only for contained users.
ALLOW_ENCRYPTED_VALUE_MODIFICATIONS = [ ON | OFF ]
Suppresses cryptographic metadata checks on the server in bulk copy operations. This enables the user to bulk copy encrypted data between tables or databases, without decrypting the data. The default is OFF.
Warning
Improper use of this option can lead to data corruption. For more information, see Migrate Sensitive Data Protected by Always Encrypted.
Remarks
The default schema will be the first schema that will be searched by the server when it resolves the names of objects for this database user. Unless otherwise specified, the default schema will be the owner of objects created by this database user.
If the user has a default schema, that default schema will used. If the user doesn't have a default schema, but the user is a member of a group that has a default schema, the default schema of the group will be used. If the user doesn't have a default schema, and is a member of more than one group, the default schema for the user will be that of the Windows group with the lowest principal_id and an explicitly set default schema. If no default schema can be determined for a user, the dbo schema will be used.
DEFAULT_SCHEMA can be set to a schema that doesn't currently occur in the database. Therefore, you can assign a DEFAULT_SCHEMA to a user before that schema is created.
DEFAULT_SCHEMA can't be specified for a user who is mapped to a certificate, or an asymmetric key.
Important
The value of DEFAULT_SCHEMA is ignored if the user is a member of the sysadmin fixed server role. All members of the sysadmin fixed server role have a default schema of dbo
.
You can change the name of a user who is mapped to a Windows login or group only when the SID of the new user name matches the SID that is recorded in the database. This check helps prevent spoofing of Windows logins in the database.
The WITH LOGIN clause enables the remapping of a user to a different login. Users without a login, users mapped to a certificate, or users mapped to an asymmetric key can't be remapped with this clause. Only SQL users and Windows users (or groups) can be remapped. The WITH LOGIN clause can't be used to change the type of user, such as changing a Windows account to a SQL Server login. The only exception is when changing a Windows user to a Microsoft Entra user.
Note
The following rules do not apply to Windows users on Azure SQL Managed Instance as we do not support creating Windows logins on Azure SQL Managed Instance. The WITH LOGIN option can only be used if Microsoft Entra logins are present.
The name of the user will be automatically renamed to the login name if the following conditions are true.
The user is a Windows user.
The name is a Windows name (contains a backslash).
No new name was specified.
The current name differs from the login name.
Otherwise, the user won't be renamed unless the caller additionally invokes the NAME clause.
The name of a user mapped to a SQL Server login, a certificate, or an asymmetric key can't contain the backslash character (\).
Caution
Beginning with SQL Server 2005, the behavior of schemas changed. As a result, code that assumes that schemas are equivalent to database users may no longer return correct results. Old catalog views, including sysobjects, should not be used in a database in which any of the following DDL statements have ever been used: CREATE SCHEMA, ALTER SCHEMA, DROP SCHEMA, CREATE USER, ALTER USER, DROP USER, CREATE ROLE, ALTER ROLE, DROP ROLE, CREATE APPROLE, ALTER APPROLE, DROP APPROLE, ALTER AUTHORIZATION. In such databases you must instead use the new catalog views. The new catalog views take into account the separation of principals and schemas that was introduced in SQL Server 2005. For more information about catalog views, see Catalog Views (Transact-SQL).
Remarks for Windows users in SQL on-premises migrated to Azure SQL Managed Instance
These remarks apply to authenticating as Windows users that have been federated and synchronized with Microsoft Entra ID.
- Validation of Windows users or groups that are mapped to Microsoft Entra ID is done by default through Graph API in all versions of the ALTER USER syntax used for migration purpose.
- On-premises users that were aliased (use a different name from the original Windows account) will keep the aliased name.
- For Microsoft Entra authentication, the LOGIN parameter applies only to Azure SQL Managed Instance and can't be used with SQL Database.
- To view logins for Microsoft Entra principals, use the following command:
select * from sys.server_principals
.
- Check the login's indicated type is
E
orX
. - PASSWORD option can't be used for Microsoft Entra users.
- In all migration cases, the roles and permissions of Windows users or groups will automatically be transferred to the new Microsoft Entra users or groups.
- A new syntax extension, FROM EXTERNAL PROVIDER is available for altering Windows users and groups from SQL on-premises to Microsoft Entra users and groups. The Windows domain must be federated with Microsoft Entra ID and all Windows domain members must exist in Microsoft Entra ID when using this extension. The FROM EXTERNAL PROVIDER syntax applies to Azure SQL Managed Instance and should be used in case Windows users do not have logins on the original SQL instance and need to be mapped to standalone Microsoft Entra database users.
- In this case, the allowable userName can be:
- A Widows user (domain\user).
- A Windows group (MyWindowsGroup).
- A Windows alias (MyWindowsAlias).
- The outcome of the ALTER command replaces the old userName with the corresponding name that is found in Microsoft Entra ID based on the original SID of the old userName. The altered name is replaced and stored in the metadata of the database:
- (domain\user) will be replaced with Microsoft Entra user@domain.com.
- (domain\MyWindowsGroup) will be replaced with Microsoft Entra group.
- (MyWindowsAlias) will remain unchanged but the SID of this user will be checked in Microsoft Entra ID.
Note
If the SID of the original user converted to objectID cannot be found in Microsoft Entra ID, the ALTER USER command will fail.
- To view altered users, use the following command:
select * from sys.database_principals
- Check the user's indicated type
E
orX
. - When NAME is used to migrate Windows users to Microsoft Entra users, the following restrictions apply:
- A valid LOGIN must be specified.
- The NAME will be checked in Microsoft Entra ID and can only be:
- The name of the LOGIN.
- An alias - the name can't exist in Microsoft Entra ID.
- In all other cases, the syntax will fail.
Security
Note
A user who has ALTER ANY USER permission can change the default schema of any user. A user who has an altered schema might unknowingly select data from the wrong table or execute code from the wrong schema.
Permissions
To change the name of a user requires the ALTER ANY USER permission.
To change the target login of a user requires the CONTROL permission on the database.
To change the user name of a user having CONTROL permission on the database requires the CONTROL permission on the database.
To change the default schema or language requires ALTER permission on the user. Users can change their own default schema or language.
Examples
All examples are executed in a user database.
A. Changing the name of a database user
The following example changes the name of the database user Mary5
to Mary51
.
ALTER USER Mary5 WITH NAME = Mary51;
GO
B. Changing the default schema of a user
The following example changes the default schema of the user Mary51
to Purchasing
.
ALTER USER Mary51 WITH DEFAULT_SCHEMA = Purchasing;
GO
C. Changing several options at once
The following example changes several options for a contained database user in one statement.
ALTER USER Philip
WITH NAME = Philipe
, DEFAULT_SCHEMA = Development
, PASSWORD = 'W1r77TT98%ab@#' OLD_PASSWORD = 'New Devel0per'
, DEFAULT_LANGUAGE= French ;
GO
D. Map the user in the database to a Microsoft Entra login after migration
The following example remaps the user, westus/joe
to a Microsoft Entra user, joe@westus.com
. This example is for logins that already exist in the managed instance. This needs to be performed after you have completed a database migration to Azure SQL Managed Instance, and want to use the Microsoft Entra login to authenticate.
ALTER USER [westus/joe] WITH LOGIN = [joe@westus.com]
E. Map an old Windows user in the database without a login in Azure SQL Managed Instance to a Microsoft Entra user
The following example remaps the user, westus/joe
without a login, to a Microsoft Entra user, joe@westus.com
. The federated user must exist in Microsoft Entra ID.
ALTER USER [westus/joe] FROM EXTERNAL PROVIDER
F. Map the user alias to an existing Microsoft Entra login
The following example remaps the user name, westus\joe
to joe_alias
. The corresponding Microsoft Entra login in this case is joe@westus.com
.
ALTER USER [westus/joe] WITH LOGIN = [joe@westus.com], name= joe_alias
G. Map a Windows group that was migrated in Azure SQL Managed Instance to a Microsoft Entra group
The following example remaps the old on-premises group, westus\mygroup
to a Microsoft Entra group mygroup
in the managed instance. The group must exist in Microsoft Entra ID.
ALTER USER [westus\mygroup] WITH LOGIN = mygroup
See also
* Azure Synapse
Analytics *
Azure Synapse Analytics
Syntax
-- Syntax for Azure Synapse
ALTER USER userName
WITH <set_item> [ ,...n ]
<set_item> ::=
NAME = newUserName
| LOGIN = loginName
| DEFAULT_SCHEMA = schema_name
[;]
Arguments
userName Specifies the name by which the user is identified inside this database.
LOGIN = loginName Remaps a user to another login by changing the user's Security Identifier (SID) to match the login's SID.
If the ALTER USER statement is the only statement in a SQL batch, Azure SQL Database supports the WITH LOGIN clause. If the ALTER USER statement isn't the only statement in a SQL batch or is executed in dynamic SQL, the WITH LOGIN clause isn't supported.
NAME = newUserName Specifies the new name for this user. newUserName must not already occur in the current database.
DEFAULT_SCHEMA = { schemaName | NULL } Specifies the first schema that will be searched by the server when it resolves the names of objects for this user. Setting the default schema to NULL removes a default schema from a Windows group. The NULL option can't be used with a Windows user.
Remarks
The default schema will be the first schema that will be searched by the server when it resolves the names of objects for this database user. Unless otherwise specified, the default schema will be the owner of objects created by this database user.
If the user has a default schema, that default schema will used. If the user doesn't have a default schema, but the user is a member of a group that has a default schema, the default schema of the group will be used. If the user doesn't have a default schema, and is a member of more than one group, the default schema for the user will be that of the Windows group with the lowest principal_id and an explicitly set default schema. If no default schema can be determined for a user, the dbo schema will be used.
DEFAULT_SCHEMA can be set to a schema that doesn't currently occur in the database. Therefore, you can assign a DEFAULT_SCHEMA to a user before that schema is created.
DEFAULT_SCHEMA can't be specified for a user who is mapped to a certificate, or an asymmetric key.
Important
The value of DEFAULT_SCHEMA is ignored if the user is a member of the sysadmin fixed server role. All members of the sysadmin fixed server role have a default schema of dbo
.
The WITH LOGIN clause enables the remapping of a user to a different login. Users without a login, users mapped to a certificate, or users mapped to an asymmetric key can't be remapped with this clause. Only SQL users and Windows users (or groups) can be remapped. The WITH LOGIN clause can't be used to change the type of user, such as changing a Windows account to a SQL Server login.
The name of the user will be automatically renamed to the login name if the following conditions are true.
No new name was specified.
The current name differs from the login name.
Otherwise, the user won't be renamed unless the caller additionally invokes the NAME clause.
The name of a user mapped to a SQL Server login, a certificate, or an asymmetric key can't contain the backslash character (\).
Caution
Beginning with SQL Server 2005, the behavior of schemas changed. As a result, code that assumes that schemas are equivalent to database users may no longer return correct results. Old catalog views, including sysobjects, should not be used in a database in which any of the following DDL statements have ever been used: CREATE SCHEMA, ALTER SCHEMA, DROP SCHEMA, CREATE USER, ALTER USER, DROP USER, CREATE ROLE, ALTER ROLE, DROP ROLE, CREATE APPROLE, ALTER APPROLE, DROP APPROLE, ALTER AUTHORIZATION. In such databases you must instead use the new catalog views. The new catalog views take into account the separation of principals and schemas that was introduced in SQL Server 2005. For more information about catalog views, see Catalog Views (Transact-SQL).
Security
Note
A user who has ALTER ANY USER permission can change the default schema of any user. A user who has an altered schema might unknowingly select data from the wrong table or execute code from the wrong schema.
Permissions
To change the name of a user requires the ALTER ANY USER permission.
To change the target login of a user requires the CONTROL permission on the database.
To change the user name of a user having CONTROL permission on the database requires the CONTROL permission on the database.
To change the default schema or language requires ALTER permission on the user. Users can change their own default schema or language.
Examples
All examples are executed in a user database.
A. Changing the name of a database user
The following example changes the name of the database user Mary5
to Mary51
.
ALTER USER Mary5 WITH NAME = Mary51;
GO
B. Changing the default schema of a user
The following example changes the default schema of the user Mary51
to Purchasing
.
ALTER USER Mary51 WITH DEFAULT_SCHEMA = Purchasing;
GO
See also
* Analytics
Platform System (PDW) *
Analytics Platform System
Syntax
-- Syntax for Analytics Platform System
ALTER USER userName
WITH <set_item> [ ,...n ]
<set_item> ::=
NAME = newUserName
| LOGIN = loginName
| DEFAULT_SCHEMA = schema_name
[;]
Arguments
userName Specifies the name by which the user is identified inside this database.
LOGIN = loginName Remaps a user to another login by changing the user's Security Identifier (SID) to match the login's SID.
If the ALTER USER statement is the only statement in a SQL batch, Azure SQL Database supports the WITH LOGIN clause. If the ALTER USER statement isn't the only statement in a SQL batch or is executed in dynamic SQL, the WITH LOGIN clause isn't supported.
NAME = newUserName Specifies the new name for this user. newUserName must not already occur in the current database.
DEFAULT_SCHEMA = { schemaName | NULL } Specifies the first schema that will be searched by the server when it resolves the names of objects for this user. Setting the default schema to NULL removes a default schema from a Windows group. The NULL option can't be used with a Windows user.
Remarks
The default schema will be the first schema that will be searched by the server when it resolves the names of objects for this database user. Unless otherwise specified, the default schema will be the owner of objects created by this database user.
If the user has a default schema, that default schema will used. If the user doesn't have a default schema, but the user is a member of a group that has a default schema, the default schema of the group will be used. If the user doesn't have a default schema, and is a member of more than one group, the default schema for the user will be that of the Windows group with the lowest principal_id and an explicitly set default schema. If no default schema can be determined for a user, the dbo schema will be used.
DEFAULT_SCHEMA can be set to a schema that doesn't currently occur in the database. Therefore, you can assign a DEFAULT_SCHEMA to a user before that schema is created.
DEFAULT_SCHEMA can't be specified for a user who is mapped to a certificate, or an asymmetric key.
Important
The value of DEFAULT_SCHEMA is ignored if the user is a member of the sysadmin fixed server role. All members of the sysadmin fixed server role have a default schema of dbo
.
The WITH LOGIN clause enables the remapping of a user to a different login. Users without a login, users mapped to a certificate, or users mapped to an asymmetric key can't be remapped with this clause. Only SQL users and Windows users (or groups) can be remapped. The WITH LOGIN clause can't be used to change the type of user, such as changing a Windows account to a SQL Server login.
The name of the user will be automatically renamed to the login name if the following conditions are true.
No new name was specified.
The current name differs from the login name.
Otherwise, the user won't be renamed unless the caller additionally invokes the NAME clause.
The name of a user mapped to a SQL Server login, a certificate, or an asymmetric key can't contain the backslash character (\).
Caution
Beginning with SQL Server 2005, the behavior of schemas changed. As a result, code that assumes that schemas are equivalent to database users may no longer return correct results. Old catalog views, including sysobjects, should not be used in a database in which any of the following DDL statements have ever been used: CREATE SCHEMA, ALTER SCHEMA, DROP SCHEMA, CREATE USER, ALTER USER, DROP USER, CREATE ROLE, ALTER ROLE, DROP ROLE, CREATE APPROLE, ALTER APPROLE, DROP APPROLE, ALTER AUTHORIZATION. In such databases you must instead use the new catalog views. The new catalog views take into account the separation of principals and schemas that was introduced in SQL Server 2005. For more information about catalog views, see Catalog Views (Transact-SQL).
Security
Note
A user who has ALTER ANY USER permission can change the default schema of any user. A user who has an altered schema might unknowingly select data from the wrong table or execute code from the wrong schema.
Permissions
To change the name of a user requires the ALTER ANY USER permission.
To change the target login of a user requires the CONTROL permission on the database.
To change the user name of a user having CONTROL permission on the database requires the CONTROL permission on the database.
To change the default schema or language requires ALTER permission on the user. Users can change their own default schema or language.
Examples
All examples are executed in a user database.
A. Changing the name of a database user
The following example changes the name of the database user Mary5
to Mary51
.
ALTER USER Mary5 WITH NAME = Mary51;
GO
B. Changing the default schema of a user
The following example changes the default schema of the user Mary51
to Purchasing
.
ALTER USER Mary51 WITH DEFAULT_SCHEMA = Purchasing;
GO