REVOKE Database Principal Permissions (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance
Revokes permissions granted or denied on a database user, database role, or application role.
Transact-SQL syntax conventions
Syntax
REVOKE [ GRANT OPTION FOR ] permission [ ,...n ]
ON
{ [ USER :: database_user ]
| [ ROLE :: database_role ]
| [ APPLICATION ROLE :: application_role ]
}
{ FROM | TO } <database_principal> [ ,...n ]
[ CASCADE ]
[ AS <database_principal> ]
<database_principal> ::=
Database_user
| Database_role
| Application_role
| Database_user_mapped_to_Windows_User
| Database_user_mapped_to_Windows_Group
| Database_user_mapped_to_certificate
| Database_user_mapped_to_asymmetric_key
| Database_user_with_no_login
Arguments
permission
Specifies a permission that can be revoked on the database principal. For a list of the permissions, see the Remarks section later in this topic.
USER ::database_user
Specifies the class and name of the user on which the permission is being revoked. The scope qualifier (::) is required.
ROLE ::database_role
Specifies the class and name of the role on which the permission is being revoked. The scope qualifier (::) is required.
APPLICATION ROLE ::application_role
Applies to: SQL Server 2008 (10.0.x) and later, SQL Database
Specifies the class and name of the application role on which the permission is being revoked. The scope qualifier (::) is required.
GRANT OPTION
Indicates that the right to grant the specified permission to other principals will be revoked. The permission itself will not be revoked.
Important
If the principal has the specified permission without the GRANT option, the permission itself will be revoked.
CASCADE
Indicates that the permission being revoked is also revoked from other principals to which it has been granted or denied by this principal.
Caution
A cascaded revocation of a permission granted WITH GRANT OPTION will revoke both GRANT and DENY of that permission.
AS <database_principal> Specifies a principal from which the principal executing this query derives its right to revoke the permission.
Database_user
Specifies a database user.
Database_role
Specifies a database role.
Application_role
Applies to: SQL Server 2008 (10.0.x) and later, SQL Database
Specifies an application role.
Database_user_mapped_to_Windows_User
Applies to: SQL Server 2008 (10.0.x) and later
Specifies a database user mapped to a Windows user.
Database_user_mapped_to_Windows_Group
Applies to: SQL Server 2008 (10.0.x) and later
Specifies a database user mapped to a Windows group.
Database_user_mapped_to_certificate
Applies to: SQL Server 2008 (10.0.x) and later
Specifies a database user mapped to a certificate.
Database_user_mapped_to_asymmetric_key
Applies to: SQL Server 2008 (10.0.x) and later
Specifies a database user mapped to an asymmetric key.
Database_user_with_no_login
Specifies a database user with no corresponding server-level principal.
Remarks
Database User Permissions
A database user is a database-level securable contained by the database that is its parent in the permissions hierarchy. The most specific and limited permissions that can be revoked on a database user are listed in the following table, together with the more general permissions that include them by implication.
Database user permission | Implied by database user permission | Implied by database permission |
---|---|---|
CONTROL | CONTROL | CONTROL |
IMPERSONATE | CONTROL | CONTROL |
ALTER | CONTROL | ALTER ANY USER |
VIEW DEFINITION | CONTROL | VIEW DEFINITION |
Database Role Permissions
A database role is a database-level securable contained by the database that is its parent in the permissions hierarchy. The most specific and limited permissions that can be revoked on a database role are listed in the following table, together with the more general permissions that include them by implication.
Database role permission | Implied by database role permission | Implied by database permission |
---|---|---|
CONTROL | CONTROL | CONTROL |
TAKE OWNERSHIP | CONTROL | CONTROL |
ALTER | CONTROL | ALTER ANY ROLE |
VIEW DEFINITION | CONTROL | VIEW DEFINITION |
Application Role Permissions
An application role is a database-level securable contained by the database that is its parent in the permissions hierarchy. The most specific and limited permissions that can be revoked on an application role are listed in the following table, together with the more general permissions that include them by implication.
Application role permission | Implied by application role permission | Implied by database permission |
---|---|---|
CONTROL | CONTROL | CONTROL |
ALTER | CONTROL | ALTER ANY APPLICATION ROLE |
VIEW DEFINITION | CONTROL | VIEW DEFINITION |
Permissions
Requires CONTROL permission on the specified principal, or a higher permission that implies CONTROL permission.
Grantees of CONTROL permission on a database, such as members of the db_owner fixed database role, can grant any permission on any securable in the database.
Examples
A. Revoking CONTROL permission on a user from another user
The following example revokes CONTROL
permission on AdventureWorks2022
user Wanida
from user RolandX
.
USE AdventureWorks2022;
REVOKE CONTROL ON USER::Wanida FROM RolandX;
GO
B. Revoking VIEW DEFINITION permission on a role from a user to which it was granted WITH GRANT OPTION
The following example revokes VIEW DEFINITION
permission on AdventureWorks2022
role SammamishParking
from database user JinghaoLiu
. The CASCADE
option is specified because the user JinghaoLiu
was granted VIEW DEFINITION
permission WITH GRANT OPTION
.
USE AdventureWorks2022;
REVOKE VIEW DEFINITION ON ROLE::SammamishParking
FROM JinghaoLiu CASCADE;
GO
C. Revoking IMPERSONATE permission on a user from an application role
The following example revokes IMPERSONATE
permission on the user HamithaL
from AdventureWorks2022
application role AccountsPayable17
.
Applies to: SQL Server 2008 (10.0.x) and later, SQL Database
USE AdventureWorks2022;
REVOKE IMPERSONATE ON USER::HamithaL FROM AccountsPayable17;
GO
See Also
GRANT Database Principal Permissions (Transact-SQL)
DENY Database Principal Permissions (Transact-SQL)
sys.database_principals (Transact-SQL)
sys.database_permissions (Transact-SQL)
CREATE USER (Transact-SQL)
CREATE APPLICATION ROLE (Transact-SQL)
CREATE ROLE (Transact-SQL)
GRANT (Transact-SQL)
Permissions (Database Engine)
Principals (Database Engine)