REVOKE Server Permissions (Transact-SQL)

Removes server-level GRANT and DENY permissions.

Topic link iconTransact-SQL Syntax Conventions

Syntax

REVOKE [ GRANT OPTION FOR ] permission  [ ,...n ] 
    { TO | FROM } <grantee_principal> [ ,...n ]
        [ CASCADE ]
    [ AS <grantor_principal> ] 

<grantee_principal> ::=SQL_Server_login 
        | SQL_Server_login_mapped_to_Windows_login
    | SQL_Server_login_mapped_to_Windows_group
    | SQL_Server_login_mapped_to_certificate
    | SQL_Server_login_mapped_to_asymmetric_key<grantor_principal> ::=SQL_Server_login 
    | SQL_Server_login_mapped_to_Windows_login
    | SQL_Server_login_mapped_to_Windows_group
    | SQL_Server_login_mapped_to_certificate
    | SQL_Server_login_mapped_to_asymmetric_key

Arguments

  • permission
    Specifies a permission that can be granted on a server. For a list of the permissions, see the Remarks section later in this topic.

  • { TO | FROM } <grantee_principal>
    Specifies the principal from which the permission is being revoked.

  • AS <grantor_principal>
    Specifies the principal from which the principal executing this query derives its right to revoke the permission.

  • GRANT OPTION FOR
    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.

    Warning

    A cascaded revocation of a permission granted WITH GRANT OPTION will revoke both GRANT and DENY of that permission.

  • SQL_Server_login
    Specifies a SQL Server login.

  • SQL_Server_login_mapped_to_Windows_login
    Specifies a SQL Server login mapped to a Windows login.

  • SQL_Server_login_mapped_to_Windows_group
    Specifies a SQL Server login mapped to a Windows group.

  • SQL_Server_login_mapped_to_certificate
    Specifies a SQL Server login mapped to a certificate.

  • SQL_Server_login_mapped_to_asymmetric_key
    Specifies a SQL Server login mapped to an asymmetric key.

Remarks

Permissions at the server scope can be revoked only when the current database is master.

REVOKE removes both GRANT and DENY permissions.

Use REVOKE GRANT OPTION FOR to revoke the right to regrant the specified permission. If the principal has the permission with the right to grant it, the right to grant the permission will be revoked, and the permission itself will not be revoked. But if the principal has the specified permission without the GRANT option, the permission itself will be revoked.

Information about server permissions is visible in the sys.server_permissions catalog view, and information about server principals is visible in the sys.server_principals catalog view. Information about membership of server roles is visible in the sys.server_role_members catalog view.

A server is the highest level of the permissions hierarchy. The most specific and limited permissions that can be revoked on a server are listed in the following table.

Server permission

Implied by server permission

ADMINISTER BULK OPERATIONS

CONTROL SERVER

ALTER ANY CONNECTION

CONTROL SERVER

ALTER ANY CREDENTIAL

CONTROL SERVER

ALTER ANY DATABASE

CONTROL SERVER

ALTER ANY ENDPOINT

CONTROL SERVER

ALTER ANY EVENT NOTIFICATION

CONTROL SERVER

ALTER ANY LINKED SERVER

CONTROL SERVER

ALTER ANY LOGIN

CONTROL SERVER

ALTER ANY SERVER AUDIT

CONTROL SERVER

ALTER RESOURCES

CONTROL SERVER

ALTER SERVER STATE

CONTROL SERVER

ALTER SETTINGS

CONTROL SERVER

ALTER TRACE

CONTROL SERVER

AUTHENTICATE SERVER

CONTROL SERVER

CONNECT SQL

CONTROL SERVER

CONTROL SERVER

CONTROL SERVER

CREATE ANY DATABASE

ALTER ANY DATABASE

CREATE DDL EVENT NOTIFICATION

ALTER ANY EVENT NOTIFICATION

CREATE ENDPOINT

ALTER ANY ENDPOINT

CREATE TRACE EVENT NOTIFICATION

ALTER ANY EVENT NOTIFICATION

EXTERNAL ACCESS ASSEMBLY

CONTROL SERVER

SHUTDOWN

CONTROL SERVER

UNSAFE ASSEMBLY

CONTROL SERVER

VIEW ANY DATABASE

VIEW ANY DEFINITION

VIEW ANY DEFINITION

CONTROL SERVER

VIEW SERVER STATE

ALTER SERVER STATE

Permissions

Requires CONTROL SERVER permission or membership in the sysadmin fixed server role.

Examples

A. Revoking a permission from a login

The following example revokes VIEW SERVER STATE permission from the SQL Server login WanidaBenshoof.

USE master;
REVOKE VIEW SERVER STATE FROM WanidaBenshoof;
GO

B. Revoking the WITH GRANT option

The following example revokes the right to grant CONNECT SQL from the SQL Server login JanethEsteves.

USE master;
REVOKE GRANT OPTION FOR CONNECT SQL FROM JanethEsteves;
GO

The login still has CONNECT SQL permission, but it can no longer grant that permission to other principals.