GRANT Type Permissions (Transact-SQL)

GRANT Type Permissions (Transact-SQL)

 

Updated: June 10, 2016

THIS TOPIC APPLIES TO:yesSQL Server (starting with 2008)yesAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Grants permissions on a type.

Topic link icon Transact-SQL Syntax Conventions

  
GRANT permission  [ ,...n ] ON TYPE :: [ schema_name . ] type_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  

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

ON TYPE :: [ schema_name. ] type_name
Specifies the type on which the permission is being granted. The scope qualifier (::) is required. If schema_name is not specified, the default schema will be used. If schema_name is specified, the schema 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

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.

A type is a schema-level securable contained by the schema that is its parent in the permissions hierarchy.

System_CAPS_ICON_important.jpg Important


GRANT, DENY, and REVOKE permissions do not apply to system types. User-defined types can be granted permissions. For more information about user-defined types, see Working with User-Defined Types in SQL Server.

The most specific and limited permissions that can be granted on a type are listed in the following table, together with the more general permissions that include them by implication.

Type permissionImplied by type permissionImplied by schema permission
CONTROLCONTROLCONTROL
EXECUTECONTROLEXECUTE
REFERENCESCONTROLREFERENCES
TAKE OWNERSHIPCONTROLCONTROL
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.

ASAdditional 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 loginIMPERSONATE 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_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 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_securityadmin fixed 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.

The following example grants VIEW DEFINITION permission with GRANT OPTION on the user-defined type PhoneNumber to user KhalidR. PhoneNumber is located in the schema Telemarketing.

GRANT VIEW DEFINITION ON TYPE::Telemarketing.PhoneNumber   
    TO KhalidR WITH GRANT OPTION;  
GO  

DENY Type Permissions (Transact-SQL)
REVOKE Type Permissions (Transact-SQL)
CREATE TYPE (Transact-SQL)
Permissions (Database Engine)
Securables
Principals (Database Engine)

Community Additions

ADD
Show:
© 2016 Microsoft