GRANT 服务器权限 (Transact-SQL)GRANT Server Permissions (Transact-SQL)

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

授予服务器的权限。Grants permissions on a server.

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

语法Syntax

  
GRANT permission [ ,...n ]   
    TO <grantee_principal> [ ,...n ] [ WITH GRANT OPTION ]  
    [ AS <grantor_principal> ]  
  
<grantee_principal> ::= SQL_Server_login   
    | SQL_Server_login_mapped_to_Windows_login  
    | SQL_Server_login_mapped_to_Windows_group  
    | SQL_Server_login_mapped_to_certificate  
    | SQL_Server_login_mapped_to_asymmetric_key  
    | server_role  
  
<grantor_principal> ::= SQL_Server_login   
    | SQL_Server_login_mapped_to_Windows_login  
    | SQL_Server_login_mapped_to_Windows_group  
    | SQL_Server_login_mapped_to_certificate  
    | SQL_Server_login_mapped_to_asymmetric_key  
    | server_role  

参数Arguments

permission permission
指定可对服务器授予的权限。Specifies a permission that can be granted on a server. 有关权限的列表,请参阅本主题后面的“备注”部分。For a list of the permissions, see the Remarks section later in this topic.

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

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

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

SQL_Server_login SQL_Server_login
指定 SQL ServerSQL Server 登录名。Specifies a SQL ServerSQL Server login.

SQL_Server_login_mapped_to_Windows_login SQL_Server_login_mapped_to_Windows_login
指定映射到 Windows 登录名的 SQL ServerSQL Server 登录名。Specifies a SQL ServerSQL Server login mapped to a Windows login.

SQL_Server_login_mapped_to_Windows_group SQL_Server_login_mapped_to_Windows_group
指定映射到 Windows 组的 SQL ServerSQL Server 登录名。Specifies a SQL ServerSQL Server login mapped to a Windows group.

SQL_Server_login_mapped_to_certificate SQL_Server_login_mapped_to_certificate
指定映射到证书的 SQL ServerSQL Server 登录名。Specifies a SQL ServerSQL Server login mapped to a certificate.

SQL_Server_login_mapped_to_asymmetric_key SQL_Server_login_mapped_to_asymmetric_key
指定映射到非对称密钥的 SQL ServerSQL Server 登录名。Specifies a SQL ServerSQL Server login mapped to an asymmetric key.

server_role server_role
指定用户定义的服务器角色。Specifies a user-defined server role.

备注Remarks

只有在当前数据库为 master 时,才可授予其服务器作用域内的权限。Permissions at the server scope can be granted only when the current database is master.

可以在 sys.server_permissions 目录视图中查看有关服务器权限的信息;在 sys.server_principals 目录视图中查看有关服务器主体的信息。Information about server permissions can be viewed in the sys.server_permissions catalog view, and information about server principals can be viewed in the sys.server_principals catalog view. 以及在 sys.server_role_members 目录视图中查看有关服务器角色成员身份的信息。Information about membership of server roles can be viewed in the sys.server_role_members catalog view.

服务器是权限层次结构的最高级别。A server is the highest level of the permissions hierarchy. 下表列出了可授予的对服务器最为具体的限定权限。The most specific and limited permissions that can be granted on a server are listed in the following table.

服务器权限Server permission 服务器权限隐含的权限Implied by server permission
ADMINISTER BULK OPERATIONSADMINISTER BULK OPERATIONS CONTROL SERVERCONTROL SERVER
ALTER ANY AVAILABILITY GROUPALTER ANY AVAILABILITY GROUP

适用范围SQL ServerSQL ServerSQL Server 2012 (11.x)SQL Server 2012 (11.x)当前版本)。Applies to: SQL ServerSQL Server (SQL Server 2012 (11.x)SQL Server 2012 (11.x) through current version).
CONTROL SERVERCONTROL SERVER
ALTER ANY CONNECTIONALTER ANY CONNECTION CONTROL SERVERCONTROL SERVER
ALTER ANY CREDENTIALALTER ANY CREDENTIAL CONTROL SERVERCONTROL SERVER
ALTER ANY DATABASEALTER ANY DATABASE CONTROL SERVERCONTROL SERVER
ALTER ANY ENDPOINTALTER ANY ENDPOINT CONTROL SERVERCONTROL SERVER
ALTER ANY EVENT NOTIFICATIONALTER ANY EVENT NOTIFICATION CONTROL SERVERCONTROL SERVER
ALTER ANY EVENT SESSIONALTER ANY EVENT SESSION CONTROL SERVERCONTROL SERVER
ALTER ANY LINKED SERVERALTER ANY LINKED SERVER CONTROL SERVERCONTROL SERVER
ALTER ANY LOGINALTER ANY LOGIN CONTROL SERVERCONTROL SERVER
ALTER ANY SERVER AUDITALTER ANY SERVER AUDIT CONTROL SERVERCONTROL SERVER
ALTER ANY SERVER ROLEALTER ANY SERVER ROLE

适用范围SQL ServerSQL ServerSQL Server 2012 (11.x)SQL Server 2012 (11.x)当前版本)。Applies to: SQL ServerSQL Server (SQL Server 2012 (11.x)SQL Server 2012 (11.x) through current version).
CONTROL SERVERCONTROL SERVER
ALTER RESOURCESALTER RESOURCES CONTROL SERVERCONTROL SERVER
ALTER SERVER STATEALTER SERVER STATE CONTROL SERVERCONTROL SERVER
ALTER SETTINGSALTER SETTINGS CONTROL SERVERCONTROL SERVER
ALTER TRACEALTER TRACE CONTROL SERVERCONTROL SERVER
AUTHENTICATE SERVERAUTHENTICATE SERVER CONTROL SERVERCONTROL SERVER
CONNECT ANY DATABASECONNECT ANY DATABASE

适用范围SQL ServerSQL ServerSQL Server 2014 (12.x)SQL Server 2014 (12.x)当前版本)。Applies to: SQL ServerSQL Server (SQL Server 2014 (12.x)SQL Server 2014 (12.x) through current version).
CONTROL SERVERCONTROL SERVER
CONNECT SQLCONNECT SQL CONTROL SERVERCONTROL SERVER
CONTROL SERVERCONTROL SERVER CONTROL SERVERCONTROL SERVER
CREATE ANY DATABASECREATE ANY DATABASE ALTER ANY DATABASEALTER ANY DATABASE
CREATE AVAILABILITY GROUPCREATE AVAILABILITY GROUP

适用范围SQL ServerSQL ServerSQL Server 2012 (11.x)SQL Server 2012 (11.x)当前版本)。Applies to: SQL ServerSQL Server (SQL Server 2012 (11.x)SQL Server 2012 (11.x) through current version).
ALTER ANY AVAILABILITY GROUPALTER ANY AVAILABILITY GROUP
CREATE DDL EVENT NOTIFICATIONCREATE DDL EVENT NOTIFICATION ALTER ANY EVENT NOTIFICATIONALTER ANY EVENT NOTIFICATION
CREATE ENDPOINTCREATE ENDPOINT ALTER ANY ENDPOINTALTER ANY ENDPOINT
CREATE SERVER ROLECREATE SERVER ROLE

适用范围SQL ServerSQL ServerSQL Server 2012 (11.x)SQL Server 2012 (11.x)当前版本)。Applies to: SQL ServerSQL Server (SQL Server 2012 (11.x)SQL Server 2012 (11.x) through current version).
ALTER ANY SERVER ROLEALTER ANY SERVER ROLE
CREATE TRACE EVENT NOTIFICATIONCREATE TRACE EVENT NOTIFICATION ALTER ANY EVENT NOTIFICATIONALTER ANY EVENT NOTIFICATION
EXTERNAL ACCESS ASSEMBLYEXTERNAL ACCESS ASSEMBLY CONTROL SERVERCONTROL SERVER
IMPERSONATE ANY LOGINIMPERSONATE ANY LOGIN

适用范围SQL ServerSQL ServerSQL Server 2014 (12.x)SQL Server 2014 (12.x)当前版本)。Applies to: SQL ServerSQL Server (SQL Server 2014 (12.x)SQL Server 2014 (12.x) through current version).
CONTROL SERVERCONTROL SERVER
SELECT ALL USER SECURABLESSELECT ALL USER SECURABLES

适用范围SQL ServerSQL ServerSQL Server 2014 (12.x)SQL Server 2014 (12.x)当前版本)。Applies to: SQL ServerSQL Server (SQL Server 2014 (12.x)SQL Server 2014 (12.x) through current version).
CONTROL SERVERCONTROL SERVER
关机SHUTDOWN CONTROL SERVERCONTROL SERVER
UNSAFE ASSEMBLYUNSAFE ASSEMBLY CONTROL SERVERCONTROL SERVER
VIEW ANY DATABASEVIEW ANY DATABASE VIEW ANY DEFINITIONVIEW ANY DEFINITION
VIEW ANY DEFINITIONVIEW ANY DEFINITION CONTROL SERVERCONTROL SERVER
VIEW SERVER STATEVIEW SERVER STATE ALTER SERVER STATEALTER SERVER STATE

备注Remarks

SQL Server 2014 (12.x)SQL Server 2014 (12.x) 中添加了以下三个服务器权限。The following three server permissions were added in SQL Server 2014 (12.x)SQL Server 2014 (12.x).

CONNECT ANY DATABASE 权限 CONNECT ANY DATABASE Permission
将 CONNECT ANY DATABASE 授予某个登录名,该登录名必须连接到当前存在的所有数据库和将来可能创建的任何新数据库。 Grant CONNECT ANY DATABASE to a login that must connect to all databases that currently exist and to any new databases that might be created in future. 不要在任何数据库中授予超过连接的任何权限。Does not grant any permission in any database beyond connect. 与 SELECT ALL USER SECURABLES 或 VIEW SERVER STATE 结合使用,可审核进程查看所有数据或 实例上的所有数据库状态。 SQL ServerSQL ServerCombine with SELECT ALL USER SECURABLES or VIEW SERVER STATE to allow an auditing process to view all data or all database states on the instance of SQL ServerSQL Server.

IMPERSONATE ANY LOGIN 权限 IMPERSONATE ANY LOGIN Permission
授予后,当连接到数据库时,允许中间层进程模拟连接到它的客户端帐户。When granted, allows a middle-tier process to impersonate the account of clients connecting to it, as it connects to databases. 被拒绝时,高特权的登录名可以阻止模拟其他登录名。When denied, a high privileged login can be blocked from impersonating other logins. 例如,可通过模拟其他登录名来阻止具有 CONTROL SERVER 权限的登录名。 For example, a login with CONTROL SERVER permission can be blocked from impersonating other logins.

SELECT ALL USER SECURABLES 权限 SELECT ALL USER SECURABLES Permission
授予后,作者等登录名可以查看用户可连接到的所有数据库中的数据。When granted, a login such as an auditor can view data in all databases that the user can connect to. 被拒绝时,阻止访问对象,除非这些对象处于 sys 架构中。 When denied, prevents access to objects unless they are in the sys schema.

权限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. sysadmin 固定服务器角色成员可以授予任何权限。Members of the sysadmin fixed server role can grant any permission.

示例Examples

A.A. 为登录名授予权限Granting a permission to a login

以下示例将 CONTROL SERVER 权限授予 SQL ServerSQL Server 登录名 TerryEminhizerThe following example grants CONTROL SERVER permission to the SQL ServerSQL Server login TerryEminhizer.

USE master;  
GRANT CONTROL SERVER TO TerryEminhizer;  
GO  

B.B. 授予具有 GRANT 权限的权限Granting a permission that has GRANT permission

以下示例为 ALTER ANY EVENT NOTIFICATION 登录名 SQL ServerSQL Server 授予 JanethEsteves 权限以及为其他登录名授予该权限的权限。The following example grants ALTER ANY EVENT NOTIFICATION to SQL ServerSQL Server login JanethEsteves with the right to grant that permission to another login.

USE master;  
GRANT ALTER ANY EVENT NOTIFICATION TO JanethEsteves WITH GRANT OPTION;  
GO  

C.C. 为服务器角色授予权限Granting a permission to a server role

以下示例创建两个名为 ITDevAdminITDevelopers 的服务器角色。The following example creates two server roles named ITDevAdmin and ITDevelopers. 它为用户定义的服务器角色 ALTER ANY DATABASE 授予 ITDevAdmin 权限(包括 WITH GRANT 选项),以便 ITDevAdmin 服务器角色可以重新分配 ALTER ANY DATABASE 权限。It grants the ALTER ANY DATABASE permission to the ITDevAdmin user-defined server role including the WITH GRANT option so that the ITDevAdmin server role can reassign the ALTER ANY DATABASE permission. 然后,该示例为 ITDevelopers 授予权限以使用 ALTER ANY DATABASE 服务器角色的 ITDevAdmin 权限。Then, the example grants the ITDevelopers the permission to use the ALTER ANY DATABASE permission of the ITDevAdmin server role.

USE master;  
CREATE SERVER ROLE ITDevAdmin ;  
CREATE SERVER ROLE ITDevelopers ;  
GRANT ALTER ANY DATABASE TO ITDevAdmin WITH GRANT OPTION ;  
GRANT ALTER ANY DATABASE TO ITDevelopers AS ITDevAdmin ;  
GO  

另请参阅See Also

GRANT (Transact-SQL) GRANT (Transact-SQL)
DENY (Transact-SQL) DENY (Transact-SQL)
DENY 服务器权限 (Transact-SQL) DENY Server Permissions (Transact-SQL)
REVOKE 服务器权限 (Transact-SQL) REVOKE Server Permissions (Transact-SQL)
权限层次结构(数据库引擎) Permissions Hierarchy (Database Engine)
主体(数据库引擎) Principals (Database Engine)
权限(数据库引擎) Permissions (Database Engine)
sys.fn_builtin_permissions (Transact-SQL) sys.fn_builtin_permissions (Transact-SQL)
sys.fn_my_permissions (Transact-SQL) sys.fn_my_permissions (Transact-SQL)
HAS_PERMS_BY_NAME (Transact-SQL)HAS_PERMS_BY_NAME (Transact-SQL)