Compartilhar via


REVOKE Server Principal Permissions (Transact-SQL)

Revokes permissions granted or denied on a SQL Server login.

Topic link iconTransact-SQL Syntax Conventions

Syntax

REVOKE [ GRANT OPTION FOR ] permission [ ,...n ] } 
    ON LOGIN :: SQL_Server_login
    { FROM | TO } <server_principal> [ ,...n ]
    [ CASCADE ]
    [ AS SQL_Server_login ] 

<server_principal> ::= 
        SQL_Server_login
    | SQL_Server_login_from_Windows_login 
    | SQL_Server_login_from_certificate 
    | SQL_Server_login_from_AsymKey   

Arguments

  • permission
    Specifies a permission that can be revoked on a SQL Server login. For a list of the permissions, see the Remarks section later in this topic.
  • LOGIN :: SQL_Server_login
    Specifies the SQL Server login on which the permission is being revoked. The scope qualifier (::) is required.
  • { FROM | TO } SQL_Server_login
    Specifies the SQL Server login from which the permission is being revoked.
  • SQL_Server_login
    Specifies the name of a SQL Server login.
  • SQL_Server_login_from_Windows_login
    Specifies the name of a SQL Server login created from a Windows login.
  • SQL_Server_login_from_certificate
    Specifies the name of a SQL Server login mapped to a certificate.
  • SQL_Server_login_from_AsymKey
    Specifies the name of a SQL Server login mapped to an asymmetric key.
  • 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.

    Warning

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

  • AS SQL_Server_login
    Specifies the SQL Server login from which the principal executing this query derives its right to revoke the permission.

Remarks

A SQL Server login is a server-level securable. The most specific and limited permissions that can be revoked on a SQL Server login are listed in the following table, together with the more general permissions that include them by implication.

SQL Server login permission Implied by SQL Server login permission Implied by server permission

CONTROL

CONTROL

CONTROL SERVER

IMPERSONATE

CONTROL

CONTROL SERVER

VIEW DEFINITION

CONTROL

VIEW ANY DEFINITION

ALTER

CONTROL

ALTER ANY LOGIN

Permissions

Requires CONTROL permission on the login or ALTER ANY LOGIN permission on the server.

Examples

A. Revoking IMPERSONATE permission on a login

The following example revokes IMPERSONATE permission on the SQL Server login WanidaBenshoof from a SQL Server login created from the Windows user AdvWorks\YoonM.

USE master;
REVOKE IMPERSONATE ON LOGIN::WanidaBenshoof FROM [AdvWorks\YoonM];
GO

B. Revoking VIEW DEFINITION permission with CASCADE

The following example revokes VIEW DEFINITION permission on the SQL Server login EricKurjan from the SQL Server login RMeyyappan. The CASCADE option indicates that VIEW DEFINITION permission on EricKurjan will also be revoked from the principals to which RMeyyappan granted this permission.

USE master;
REVOKE VIEW DEFINITION ON LOGIN::EricKurjan FROM RMeyyappan 
    CASCADE;
GO 

See Also

Reference

sys.server_principals (Transact-SQL)
sys.server_permissions (Transact-SQL)
GRANT Server Principal Permissions (Transact-SQL)
DENY Server Principal Permissions (Transact-SQL)
CREATE LOGIN (Transact-SQL)

Other Resources

Principals
Permissions

Help and Information

Getting SQL Server 2005 Assistance