GRANT Symmetric Key Permissions (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics
Grants permissions on a symmetric key.
Transact-SQL syntax conventions
Note
This syntax is not supported by serverless SQL pool in Azure Synapse Analytics.
Syntax
GRANT permission [ ,...n ]
ON SYMMETRIC KEY :: symmetric_key_name
TO <database_principal> [ ,...n ] [ WITH GRANT OPTION ]
[ AS <database_principal> ]
<database_principal> ::=
Database_user
| Database_role
| Application_role
| Database_user_mapped_to_Windows_User
| Database_user_mapped_to_Windows_Group
| Database_user_mapped_to_certificate
| Database_user_mapped_to_asymmetric_key
| Database_user_with_no_login
Arguments
permission
Specifies a permission that can be granted on a symmetric key. For a list of the permissions, see the Remarks section later in this topic.
ON SYMMETRIC KEY ::asymmetric_key_name
Specifies the symmetric key on which the permission is being granted. The scope qualifier (::) is required.
TO <database_principal>
Specifies the principal to which the permission is being granted.
WITH GRANT OPTION
Indicates that the principal will also be given the ability to grant the specified permission to other principals.
AS <database_principal> Specifies a principal from which the principal executing this query derives its right to grant the permission.
Database_user
Specifies a database user.
Database_role
Specifies a database role.
Application_role
Specifies an application role.
Database_user_mapped_to_Windows_User
Specifies a database user mapped to a Windows user.
Database_user_mapped_to_Windows_Group
Specifies a database user mapped to a Windows group.
Database_user_mapped_to_certificate
Specifies a database user mapped to a certificate.
Database_user_mapped_to_asymmetric_key
Specifies a database user mapped to an asymmetric key.
Database_user_with_no_login
Specifies a database user with no corresponding server-level principal.
Remarks
Information about symmetric keys is visible in the sys.symmetric_keys catalog view.
A symmetric key is a database-level securable contained by the database that is its parent in the permissions hierarchy. The most specific and limited permissions that can be granted on a symmetric key are listed in the following table, together with the more general permissions that include them by implication.
Symmetric key permission | Implied by symmetric key permission | Implied by database permission |
---|---|---|
ALTER | CONTROL | ALTER ANY SYMMETRIC KEY |
CONTROL | CONTROL | CONTROL |
REFERENCES | CONTROL | REFERENCES |
TAKE OWNERSHIP | CONTROL | CONTROL |
VIEW DEFINITION | CONTROL | VIEW DEFINITION |
Permissions
The grantor (or the principal specified with the AS option) must have either the permission itself with GRANT OPTION, or a higher permission that implies the permission being granted.
If you are using the AS option, the following additional requirements apply.
AS granting_principal | Additional permission required |
---|---|
Database user | IMPERSONATE permission on the user, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Database user mapped to a Windows login | IMPERSONATE permission on the user, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Database user mapped to a Windows group | Membership in the Windows group, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Database user mapped to a certificate | Membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Database user mapped to an asymmetric key | Membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Database user not mapped to any server principal | IMPERSONATE permission on the user, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Database role | ALTER permission on the role, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Application role | ALTER permission on the role, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role. |
Principals with CONTROL permission on a securable can grant permission on that securable.
Grantees of CONTROL SERVER permission, such as members of the sysadmin fixed server role, can grant any permission on any securable in the server. Grantees of CONTROL permission on a database, such as members of the db_owner fixed database role, can grant any permission on any securable in the database.
Examples
The following example grants ALTER
permission on the symmetric key SamInventory42
to the database user HamidS
.
USE AdventureWorks2022;
GRANT ALTER ON SYMMETRIC KEY::SamInventory42 TO HamidS;
GO
See Also
sys.symmetric_keys (Transact-SQL)
DENY Symmetric Key Permissions (Transact-SQL)
REVOKE Symmetric Key Permissions (Transact-SQL)
CREATE SYMMETRIC KEY (Transact-SQL)
Permissions (Database Engine)
Principals (Database Engine)
Encryption Hierarchy