REVOKE Availability Group Permissions (Transact-SQL)

Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance SQL database in Microsoft Fabric

Revokes permissions on an Always On availability group.

Transact-SQL syntax conventions

Syntax

REVOKE [ GRANT OPTION FOR ] permission  [ ,...n ]   
    ON AVAILABILITY GROUP :: availability_group_name  
    { 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 an availability group. For a list of the permissions, see the Remarks section later in this topic.

ON AVAILABILITY GROUP ::availability_group_name
Specifies the availability group on which the permission is being revoked. The scope qualifier (::) is required.

{ FROM | TO } <server_principal> Specifies the SQL Server login to 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.

Important

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

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

Information about availability groups is visible in the sys.availability_groups (Transact-SQL) catalog view. 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.

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

Availability group permission Implied by availability group permission Implied by server permission
ALTER CONTROL ALTER ANY AVAILABILITY GROUP
CONNECT CONTROL CONTROL SERVER
CONTROL CONTROL CONTROL SERVER
TAKE OWNERSHIP CONTROL CONTROL SERVER
VIEW DEFINITION CONTROL VIEW ANY DEFINITION

Permissions

Requires CONTROL permission on the availability group or ALTER ANY AVAILABILITY GROUP permission on the server.

Examples

A. Revoking VIEW DEFINITION permission on an availability group

The following example revokes VIEW DEFINITION permission on availability group MyAg to SQL Server login ZArifin.

USE master;  
REVOKE VIEW DEFINITION ON AVAILABILITY GROUP::MyAg TO ZArifin;  
GO  

B. Revoking TAKE OWNERSHIP permission with the CASCADE

The following example revokes TAKE OWNERSHIP permission on availability group MyAg to SQL Server user PKomosinski and from all principals to which PKomosinski granted TAKE OWNERSHIP on MyAg.

USE master;  
REVOKE TAKE OWNERSHIP ON AVAILABILITY GROUP::MyAg TO PKomosinski   
    CASCADE;  
GO  

C. Revoking a previously granted WITH GRANT OPTION clause

If a permission was granted using the WITH GRANT OPTION, use REVOKE GRANT OPTION FOR ... to remove the WITH GRANT OPTION. The following example grants the permission and then removes the WITH GRANT portion of the permission.

USE master;  
GRANT CONTROL ON AVAILABILITY GROUP::MyAg TO PKomosinski   
    WITH GRANT OPTION;  
GO  
REVOKE GRANT OPTION FOR CONTROL ON AVAILABILITY GROUP::MyAg TO PKomosinski  
CASCADE  
GO  

See Also

GRANT Availability Group Permissions (Transact-SQL)
DENY Availability Group Permissions (Transact-SQL)
CREATE AVAILABILITY GROUP (Transact-SQL)
sys.availability_groups (Transact-SQL)
Always On Availability Groups Catalog Views (Transact-SQL)
Permissions (Database Engine)
Principals (Database Engine)