DENY Availability Group Permissions (Transact-SQL)

Applies to: SQL Server

Denies permissions on an Always On availability group in SQL Server.

Transact-SQL syntax conventions

Syntax

DENY permission  [ ,...n ] ON AVAILABILITY GROUP :: availability_group_name  
        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  

Note

To view Transact-SQL syntax for SQL Server 2014 (12.x) and earlier versions, see Previous versions documentation.

Arguments

permission
Specifies a permission that can be denied 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 denied. The scope qualifier (::) is required.

TO <server_principal>
Specifies the SQL Server login to which the permission is being denied.

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.

CASCADE
Indicates that the permission being denied is also denied to other principals to which it has been granted by this principal.

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

Remarks

Permissions at the server scope can be denied 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 denied 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. Denying VIEW DEFINITION permission on an availability group

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

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

B. Denying TAKE OWNERSHIP permission with the CASCADE OPTION

The following example denies TAKE OWNERSHIP permission on availability group MyAg to SQL Server user PKomosinski with the CASCADE option.

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

See Also

REVOKE Availability Group Permissions (Transact-SQL)
GRANT 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)