Skip to content

Latest commit

 

History

History
129 lines (98 loc) · 6.63 KB

grant-availability-group-permissions-transact-sql.md

File metadata and controls

129 lines (98 loc) · 6.63 KB
title titleSuffix description author ms.author ms.date ms.service ms.subservice ms.topic helpviewer_keywords dev_langs
GRANT Availability Group Permissions
SQL Server (Transact-SQL)
Grant permissions on an Always On availability group.
VanMSFT
vanto
06/12/2017
sql
t-sql
reference
Availability Groups [SQL Server], permissions
GRANT statement, availability groups
granting permissions, [SQL Server], availability groups
permissions [SQL Server], availability group
TSQL

GRANT Availability Group Permissions (Transact-SQL)

[!INCLUDE SQL Server]

Grants permissions on an Always On availability group.

:::image type="icon" source="../../includes/media/topic-link-icon.svg" border="false"::: Transact-SQL syntax conventions

Syntax

GRANT permission  [ ,...n ] ON AVAILABILITY GROUP :: availability_group_name  
        TO < server_principal >  [ ,...n ]  
    [ WITH GRANT OPTION ]  
    [ 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 granted 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 granted. The scope qualifier (::) is required.

TO <server_principal>
Specifies the [!INCLUDEssNoVersion] login to which the permission is being granted.

SQL_Server_login
Specifies the name of a [!INCLUDEssNoVersion] login.

SQL_Server_login_from_Windows_login
Specifies the name of a [!INCLUDEssNoVersion] login created from a Windows login.

SQL_Server_login_from_certificate
Specifies the name of a [!INCLUDEssNoVersion] login mapped to a certificate.

SQL_Server_login_from_AsymKey
Specifies the name of a [!INCLUDEssNoVersion] login mapped to an asymmetric key.

WITH GRANT OPTION
Indicates that the principal will also be given the ability to grant the specified permission to other principals.

AS SQL_Server_login
Specifies the [!INCLUDEssNoVersion] login from which the principal executing this query derives its right to grant the permission.

Remarks

Permissions at the server scope can be granted 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 granted 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

For a chart of all [!INCLUDEssDE] permissions, see Database Engine Permission Poster.

Permissions

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

Examples

A. Granting VIEW DEFINITION permission on an availability group

The following example grants VIEW DEFINITION permission on availability group MyAg to [!INCLUDEssNoVersion] login ZArifin.

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

B. Granting TAKE OWNERSHIP permission with the GRANT OPTION

The following example grants TAKE OWNERSHIP permission on availability group MyAg to [!INCLUDEssNoVersion] user PKomosinski with the GRANT OPTION.

USE master;  
GRANT TAKE OWNERSHIP ON AVAILABILITY GROUP::MyAg TO PKomosinski   
    WITH GRANT OPTION;  
GO  

C. Granting CONTROL permission on an availability group

The following example grants CONTROL permission on availability group MyAg to [!INCLUDEssNoVersion] user PKomosinski. CONTROL allows the login complete control of the availability group, even though they are not the owner of the availability group. To change the ownership, see ALTER AUTHORIZATION (Transact-SQL).

USE master;  
GRANT CONTROL ON AVAILABILITY GROUP::MyAg TO PKomosinski;  
GO  

See Also

REVOKE 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)