Delen via


GRANT Server Permissions (Transact-SQL)

Grants permissions on a server.

Topic link iconTransact-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<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

Arguments

  • 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>
    Specifies the principal to which the permission is being granted.

  • AS <grantor_principal>
    Specifies the principal from which the principal executing this query derives its right to grant the permission.

  • WITH GRANT OPTION
    Indicates that the principal will also be given the ability to grant the specified permission to other principals.

  • SQL_Server_login
    Specifies a SQL Server login.

  • SQL_Server_login_mapped_to_Windows_login
    Specifies a SQL Server login mapped to a Windows login.

  • SQL_Server_login_mapped_to_Windows_group
    Specifies a SQL Server login mapped to a Windows group.

  • SQL_Server_login_mapped_to_certificate
    Specifies a SQL Server login mapped to a certificate.

  • SQL_Server_login_mapped_to_asymmetric_key
    Specifies a SQL Server login mapped to an asymmetric key.

Remarks

Permissions at the server scope can be granted only when the current database is master.

Information about server permissions is visible in the sys.server_permissions catalog view, and information about server principals is visible in the sys.server_principals catalog view. Information about membership of server roles is visible 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 OPERATIONS

CONTROL SERVER

ALTER ANY CONNECTION

CONTROL SERVER

ALTER ANY CREDENTIAL

CONTROL SERVER

ALTER ANY DATABASE

CONTROL SERVER

ALTER ANY ENDPOINT

CONTROL SERVER

ALTER ANY EVENT NOTIFICATION

CONTROL SERVER

ALTER ANY LINKED SERVER

CONTROL SERVER

ALTER ANY LOGIN

CONTROL SERVER

ALTER ANY SERVER AUDIT

CONTROL SERVER

ALTER RESOURCES

CONTROL SERVER

ALTER SERVER STATE

CONTROL SERVER

ALTER SETTINGS

CONTROL SERVER

ALTER TRACE

CONTROL SERVER

AUTHENTICATE SERVER

CONTROL SERVER

CONNECT SQL

CONTROL SERVER

CONTROL SERVER

CONTROL SERVER

CREATE ANY DATABASE

ALTER ANY DATABASE

CREATE DDL EVENT NOTIFICATION

ALTER ANY EVENT NOTIFICATION

CREATE ENDPOINT

ALTER ANY ENDPOINT

CREATE TRACE EVENT NOTIFICATION

ALTER ANY EVENT NOTIFICATION

EXTERNAL ACCESS ASSEMBLY

CONTROL SERVER

SHUTDOWN

CONTROL SERVER

UNSAFE ASSEMBLY

CONTROL SERVER

VIEW ANY DATABASE

VIEW ANY DEFINITION

VIEW ANY DEFINITION

CONTROL SERVER

VIEW SERVER STATE

ALTER SERVER STATE

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. Members of the sysadmin fixed server role can grant any permission.

Examples

A. Granting a permission to a login

The following example grants CONTROL SERVER permission to the SQL Server login TerryEminhizer.

USE master;
GRANT CONTROL SERVER TO TerryEminhizer;
GO

B. Granting a permission that has GRANT permission

The following example grants ALTER ANY EVENT NOTIFICATION to SQL 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