GRANT Availability Group Permissions (Transact-SQL)
Applies to: SQL Server
Grants permissions on an Always On availability group.
Transact-SQL syntax conventions
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
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 SQL Server login to which the permission is being granted.
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.
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 SQL Server login from which the principal executing this query derives its right to grant the permission.
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 Database Engine permissions, see Database Engine Permission Poster.
Requires CONTROL permission on the availability group or ALTER ANY AVAILABILITY GROUP permission on the server.
The following example grants VIEW DEFINITION
permission on availability group MyAg
to SQL Server login ZArifin
.
USE master;
GRANT VIEW DEFINITION ON AVAILABILITY GROUP::MyAg TO ZArifin;
GO
The following example grants TAKE OWNERSHIP
permission on availability group MyAg
to SQL Server user PKomosinski
with the GRANT OPTION
.
USE master;
GRANT TAKE OWNERSHIP ON AVAILABILITY GROUP::MyAg TO PKomosinski
WITH GRANT OPTION;
GO
The following example grants CONTROL
permission on availability group MyAg
to SQL Server 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
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)