GRANT Database Principal Permissions (Transact-SQL)

GRANT Database Principal Permissions (Transact-SQL)

 

Grants permissions on a database user, database role, or application role in SQL Server.

Applies to: SQL Server (SQL Server 2008 through current version), Azure SQL Database.

Topic link icon Transact-SQL Syntax Conventions

  
GRANT permission [ ,...n ]    
    ON   
    {  [ USER :: database_user ]  
     | [ ROLE :: database_role ]  
     | [ APPLICATION ROLE :: application_role ]  
    }  
    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   

permission
Specifies a permission that can be granted on the database principal. For a list of the permissions, see the Remarks section later in this topic.

USER ::database_user
Specifies the class and name of the user on which the permission is being granted. The scope qualifier (::) is required.

ROLE ::database_role
Specifies the class and name of the role on which the permission is being granted. The scope qualifier (::) is required.

APPLICATION ROLE ::application_role

Applies to: SQL Server 2008 through SQL Server 2016, SQL Database V12.

Specifies the class and name of the application role on which the permission is being granted. The scope qualifier (::) is required.

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

Applies to: SQL Server 2008 through SQL Server 2016, SQL Database V12.

Specifies an application role.

Database_user_mapped_to_Windows_User

Applies to: SQL Server 2008 through SQL Server 2016.

Specifies a database user mapped to a Windows user.

Database_user_mapped_to_Windows_Group

Applies to: SQL Server 2008 through SQL Server 2016.

Specifies a database user mapped to a Windows group.

Database_user_mapped_to_certificate

Applies to: SQL Server 2008 through SQL Server 2016.

Specifies a database user mapped to a certificate.

Database_user_mapped_to_asymmetric_key

Applies to: SQL Server 2008 through SQL Server 2016.

Specifies a database user mapped to an asymmetric key.

Database_user_with_no_login
Specifies a database user with no corresponding server-level principal.

Information about database principals is visible in the sys.database_principals catalog view. Information about database-level permissions is visible in the sys.database_permissions catalog view.

A database user 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 database user are listed in the following table, together with the more general permissions that include them by implication.

Database user permissionImplied by database user permissionImplied by database permission
CONTROLCONTROLCONTROL
IMPERSONATECONTROLCONTROL
ALTERCONTROLALTER ANY USER
VIEW DEFINITIONCONTROLVIEW DEFINITION

A database role 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 database role are listed in the following table, together with the more general permissions that include them by implication.

Database role permissionImplied by database role permissionImplied by database permission
CONTROLCONTROLCONTROL
TAKE OWNERSHIPCONTROLCONTROL
ALTERCONTROLALTER ANY ROLE
VIEW DEFINITIONCONTROLVIEW DEFINITION

An application role 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 an application role are listed in the following, together with the more general permissions that include them by implication.

Application role permissionImplied by application role permissionImplied by database permission
CONTROLCONTROLCONTROL
ALTERCONTROLALTER ANY APPLICATION ROLE
VIEW DEFINITIONCONTROLVIEW DEFINITION

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_principalAdditional permission required
Database userIMPERSONATE 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 UserIMPERSONATE 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 GroupMembership 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 certificateMembership 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 keyMembership in the db_securityadminfixed 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 principalIMPERSONATE 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 roleALTER permission on the role, membership in the db_securityadminfixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Application roleALTER 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 that have CONTROL permission on a securable can grant permission on that securable.

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.

A. Granting CONTROL permission on a user to another user

The following example grants CONTROL permission on AdventureWorks2012 user Wanida to user RolandX.

USE AdventureWorks2012;  
GRANT CONTROL ON USER::Wanida TO RolandX;  
GO  

B. Granting VIEW DEFINITION permission on a role to a user with GRANT OPTION

The following example grants VIEW DEFINITION permission on AdventureWorks2012 role SammamishParking together with GRANT OPTION to database user JinghaoLiu.

USE AdventureWorks2012;  
GRANT VIEW DEFINITION ON ROLE::SammamishParking   
    TO JinghaoLiu WITH GRANT OPTION;  
GO  

C. Granting IMPERSONATE permission on a user to an application role

The following example grants IMPERSONATE permission on user HamithaL to AdventureWorks2012 application role AccountsPayable17.

Applies to: SQL Server 2008 through SQL Server 2016, SQL Database V12.
USE AdventureWorks2012;  
GRANT IMPERSONATE ON USER::HamithaL TO AccountsPayable17;  
GO    

DENY Database Principal Permissions (Transact-SQL)
REVOKE Database Principal Permissions (Transact-SQL)
sys.database_principals (Transact-SQL)
sys.database_permissions (Transact-SQL)
CREATE USER (Transact-SQL)
CREATE APPLICATION ROLE (Transact-SQL)
CREATE ROLE (Transact-SQL)
GRANT (Transact-SQL)
Permissions (Database Engine)
Principals (Database Engine)

Community Additions

ADD
Show:
© 2016 Microsoft