GRANT 对象权限 (Transact-SQL)GRANT Object Permissions (Transact-SQL)

适用对象:是SQL Server 是Azure SQL 数据库 是Azure Synapse Analytics (SQL DW) 是并行数据仓库 APPLIES TO: yesSQL Server yesAzure SQL Database yesAzure Synapse Analytics (SQL DW) yesParallel Data Warehouse

授予对表、视图、表值函数、存储过程、扩展存储过程、标量函数、聚合函数、服务队列或同义词的权限。Grants permissions on a table, view, table-valued function, stored procedure, extended stored procedure, scalar function, aggregate function, service queue, or synonym.

主题链接图标 TRANSACT-SQL 语法约定Topic link icon Transact-SQL Syntax Conventions

语法Syntax

GRANT <permission> [ ,...n ] ON   
    [ OBJECT :: ][ schema_name ]. object_name [ ( column [ ,...n ] ) ]  
    TO <database_principal> [ ,...n ]   
    [ WITH GRANT OPTION ]  
    [ AS <database_principal> ]  
  
<permission> ::=  
    ALL [ PRIVILEGES ] | permission [ ( column [ ,...n ] ) ]  
  
<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 permission
指定可以授予的对架构包含的对象的权限。Specifies a permission that can be granted on a schema-contained object. 有关权限的列表,请参阅本主题后面的“备注”部分。For a list of the permissions, see the Remarks section later in this topic.

ALLALL
授予 ALL 不会授予所有可能的权限。Granting ALL does not grant all possible permissions. 授予 ALL 等同于授予适用于指定对象的所有 ANSIANSI-92 权限。Granting ALL is equivalent to granting all ANSIANSI-92 permissions applicable to the specified object. 对于不同权限,ALL 的含义有所不同:The meaning of ALL varies as follows:

  • 标量值函数权限:EXECUTE、REFERENCES。Scalar function permissions: EXECUTE, REFERENCES.
  • 表值函数权限:DELETE、INSERT、REFERENCES、SELECT、UPDATE。Table-valued function permissions: DELETE, INSERT, REFERENCES, SELECT, UPDATE.
  • 存储过程权限:EXECUTE。Stored procedure permissions: EXECUTE.
  • 表权限:DELETE、INSERT、REFERENCES、SELECT、UPDATE。Table permissions: DELETE, INSERT, REFERENCES, SELECT, UPDATE.
  • 视图权限:DELETE、INSERT、REFERENCES、SELECT、UPDATE。View permissions: DELETE, INSERT, REFERENCES, SELECT, UPDATE.

PRIVILEGESPRIVILEGES
包含此参数以符合 ANSIANSI-92 标准。Included for ANSIANSI-92 compliance. 请不要更改 ALL 的行为。Does not change the behavior of ALL.

columncolumn
指定表、视图或表值函数中要授予对其权限的列的名称。Specifies the name of a column in a table, view, or table-valued function on which the permission is being granted. 需要使用括号 ( )。The parentheses ( ) are required. 只能授予对列的 SELECT、REFERENCES 及 UPDATE 权限。Only SELECT, REFERENCES, and UPDATE permissions can be granted on a column. 可以在权限子句中或在安全对象名之后指定 column 。column can be specified in the permissions clause or after the securable name.

注意

表级 DENY 并不优先于列级 GRANT。A table-level DENY does not take precedence over a column-level GRANT. 保留了权限层次结构中的这种不一致性以保持向后兼容。This inconsistency in the permissions hierarchy has been preserved for backward compatibility.

ON [ OBJECT :: ] [ schema_name ] . ON [ OBJECT :: ] [ schema_name ] . object_nameobject_name
指定要授予对其权限的对象。Specifies the object on which the permission is being granted. 如果指定了 schema_name,则 OBJECT 短语是可选的 。The OBJECT phrase is optional if schema_name is specified. 如果使用了 OBJECT 短语,则需要作用域限定符 (::)。If the OBJECT phrase is used, the scope qualifier (::) is required. 如果未指定 schema_name,则使用默认架构 。If schema_name is not specified, the default schema is used. 如果指定了 schema_name,则需要使用架构作用域限定符 (.) 。If schema_name is specified, the schema scope qualifier (.) is required.

TO <database_principal>TO <database_principal>
指定要向其授予权限的主体。Specifies the principal to which the permission is being granted.

WITH GRANT OPTIONWITH GRANT OPTION
指示该主体还可以向其他主体授予所指定的权限。Indicates that the principal will also be given the ability to grant the specified permission to other principals.

AS <database_principal> 指定一个主体,执行该查询的主体从该主体获得授予该权限的权利。AS <database_principal> Specifies a principal from which the principal executing this query derives its right to grant the permission.

Database_user Database_user
指定数据库用户。Specifies a database user.

Database_role Database_role
指定数据库角色。Specifies a database role.

Application_role Application_role
指定应用程序角色。Specifies an application role.

Database_user_mapped_to_Windows_User Database_user_mapped_to_Windows_User
指定映射到 Windows 用户的数据库用户。Specifies a database user mapped to a Windows user.

Database_user_mapped_to_Windows_Group Database_user_mapped_to_Windows_Group
指定映射到 Windows 组的数据库用户。Specifies a database user mapped to a Windows group.

Database_user_mapped_to_certificate Database_user_mapped_to_certificate
指定映射到证书的数据库用户。Specifies a database user mapped to a certificate.

Database_user_mapped_to_asymmetric_key Database_user_mapped_to_asymmetric_key
指定映射到非对称密钥的数据库用户。Specifies a database user mapped to an asymmetric key.

Database_user_with_no_login Database_user_with_no_login
指定无相应服务器级主体的数据库用户。Specifies a database user with no corresponding server-level principal.

RemarksRemarks

重要

在某些情况下,如果同时拥有 ALTER 权限和 REFERENCE 权限,被授权者将可以查看数据或执行未经授权的函数。A combination of ALTER and REFERENCE permissions in some cases could allow the grantee to view data or execute unauthorized functions. 例如:对表拥有 ALTER 权限和对函数拥有 REFERENCE 权限的用户可对函数创建计算列并执行该函数。For example: A user with ALTER permission on a table and REFERENCE permission on a function can create a computed column over a function and have it be executed. 在此情况下,用户可能需要对计算列具有 SELECT 权限。In this case the user would also need SELECT permission on the computed column.

可以在各种目录视图中查看对象的有关信息。Information about objects is visible in various catalog views. 有关详细信息,请参阅对象目录视图 (Transact-SQL)For more information, see Object Catalog Views (Transact-SQL).

对象是一个架构级的安全对象,包含于权限层次结构中作为其父级的架构中。An object is a schema-level securable contained by the schema that is its parent in the permissions hierarchy. 下表列出了可授予的对对象最为具体的限定权限,以及隐含这些权限的更为通用的权限。The most specific and limited permissions that can be granted on an object are listed in the following table, together with the more general permissions that include them by implication.

对象权限Object permission 对象权限隐含的权限Implied by object permission 架构权限隐含的权限Implied by schema permission
ALTERALTER CONTROLCONTROL ALTERALTER
CONTROLCONTROL CONTROLCONTROL CONTROLCONTROL
删除DELETE CONTROLCONTROL 删除DELETE
在运行 CREATE 语句前执行EXECUTE CONTROLCONTROL 在运行 CREATE 语句前执行EXECUTE
InsertINSERT CONTROLCONTROL InsertINSERT
RECEIVERECEIVE CONTROLCONTROL CONTROLCONTROL
REFERENCESREFERENCES CONTROLCONTROL REFERENCESREFERENCES
SELECTSELECT RECEIVERECEIVE SELECTSELECT
TAKE OWNERSHIPTAKE OWNERSHIP CONTROLCONTROL CONTROLCONTROL
UPDATEUPDATE CONTROLCONTROL UPDATEUPDATE
VIEW CHANGE TRACKINGVIEW CHANGE TRACKING CONTROLCONTROL VIEW CHANGE TRACKINGVIEW CHANGE TRACKING
VIEW DEFINITIONVIEW DEFINITION CONTROLCONTROL VIEW DEFINITIONVIEW DEFINITION

权限Permissions

授权者(或用 AS 选项指定的主体)必须具有带 GRANT OPTION 的相同权限,或具有隐含所授予权限的更高权限。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.

若要使用 AS 选项,还必须满足以下附加要求:If you are using the AS option, the following additional requirements apply.

ASAS 所需的其他权限Additional permission required
数据库用户Database user 对用户的 IMPERSONATE 权限、db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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.
映射到 Windows 登录名的数据库用户Database user mapped to a Windows login 对用户的 IMPERSONATE 权限、db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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.
映射到 Windows 组的数据库用户Database user mapped to a Windows Group Windows 组的成员身份、db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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 db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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 db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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 权限、db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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 权限、db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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 权限、db_securityadmin 固定数据库角色的成员身份、db_owner 固定数据库角色的成员身份或 sysadmin 固定服务器角色的成员身份。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.

示例Examples

A.A. 授予表的 SELECT 权限Granting SELECT permission on a table

以下示例授予用户 SELECTRosaQdM 数据库中表 Person.AddressAdventureWorks2012 权限。The following example grants SELECT permission to user RosaQdM on table Person.Address in the AdventureWorks2012 database.

GRANT SELECT ON OBJECT::Person.Address TO RosaQdM;  
GO  

B.B. 授予对存储过程的 EXECUTE 权限Granting EXECUTE permission on a stored procedure

以下示例授予名为 EXECUTE 的应用程序角色对存储过程 HumanResources.uspUpdateEmployeeHireInfoRecruiting11 权限。The following example grants EXECUTE permission on stored procedure HumanResources.uspUpdateEmployeeHireInfo to an application role called Recruiting11.

USE AdventureWorks2012;   
GRANT EXECUTE ON OBJECT::HumanResources.uspUpdateEmployeeHireInfo  
    TO Recruiting11;  
GO   

C.C. 使用 GRANT OPTION 授予对视图的 REFERENCES 权限Granting REFERENCES permission on a view with GRANT OPTION

以下示例使用 REFERENCES,授予用户 BusinessEntityID 对视图 HumanResources.vEmployee 中列 WanidaGRANT OPTION 权限。The following example grants REFERENCES permission on column BusinessEntityID in view HumanResources.vEmployee to user Wanida with GRANT OPTION.

GRANT REFERENCES (BusinessEntityID) ON OBJECT::HumanResources.vEmployee   
    TO Wanida WITH GRANT OPTION;  
GO  

D.D. 不使用 OBJECT 短语对表授予 SELECT 权限Granting SELECT permission on a table without using the OBJECT phrase

以下示例授予用户 SELECTRosaQdM 数据库中表 Person.AddressAdventureWorks2012 权限。The following example grants SELECT permission to user RosaQdM on table Person.Address in the AdventureWorks2012 database.

GRANT SELECT ON Person.Address TO RosaQdM;  
GO  

E.E. 向域帐户授予对表的 SELECT 权限Granting SELECT permission on a table to a domain account

以下示例授予用户 SELECTAdventureWorks2012\RosaQdM 数据库中表 Person.AddressAdventureWorks2012 权限。The following example grants SELECT permission to user AdventureWorks2012\RosaQdM on table Person.Address in the AdventureWorks2012 database.

GRANT SELECT ON Person.Address TO [AdventureWorks2012\RosaQdM];  
GO  

F.F. 将针对过程的 EXECUTE 权限授予角色Granting EXECUTE permission on a procedure to a role

以下示例创建一个角色,然后针对 EXECUTE 数据库中的过程 uspGetBillOfMaterials,将 AdventureWorks2012 权限授予该角色。The following example creates a role and then grants EXECUTE permission to the role on procedure uspGetBillOfMaterials in the AdventureWorks2012 database.

CREATE ROLE newrole ;  
GRANT EXECUTE ON dbo.uspGetBillOfMaterials TO newrole ;  
GO  

另请参阅See Also

DENY 对象权限 (Transact-SQL) DENY Object Permissions (Transact-SQL)
REVOKE 对象权限 (Transact-SQL) REVOKE Object Permissions (Transact-SQL)
对象目录视图 (Transact-SQL) Object Catalog Views (Transact-SQL)
权限(数据库引擎) Permissions (Database Engine)
主体(数据库引擎) Principals (Database Engine)
安全对象 Securables
sys.fn_builtin_permissions (Transact-SQL) sys.fn_builtin_permissions (Transact-SQL)
HAS_PERMS_BY_NAME (Transact-SQL) HAS_PERMS_BY_NAME (Transact-SQL)
sys.fn_my_permissions (Transact-SQL)sys.fn_my_permissions (Transact-SQL)