GRANT (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW) SQL analytics endpoint in Microsoft Fabric Warehouse in Microsoft Fabric SQL database in Microsoft Fabric
Grants permissions on a securable to a principal. The general concept is to GRANT <some permission> ON <some object> TO <some user, login, or group>
. For a general discussion of permissions, see Permissions (Database Engine).
Transact-SQL syntax conventions
Syntax
Syntax for SQL Server, Azure SQL Database, and Fabric SQL database.
-- Simplified syntax for GRANT
GRANT { ALL [ PRIVILEGES ] }
| permission [ ( column [ , ...n ] ) ] [ , ...n ]
[ ON [ class :: ] securable ] TO principal [ , ...n ]
[ WITH GRANT OPTION ] [ AS principal ]
Syntax for Azure Synapse Analytics, Parallel Data Warehouse, and Microsoft Fabric warehouse.
GRANT
<permission> [ , ...n ]
[ ON [ <class_type> :: ] securable ]
TO principal [ , ...n ]
[ WITH GRANT OPTION ]
[;]
<permission> ::=
{ see the tables below }
<class_type> ::=
{
LOGIN
| DATABASE
| OBJECT
| ROLE
| SCHEMA
| USER
}
Arguments
ALL
This option is deprecated and maintained only for backward compatibility. It doesn't grant all possible permissions. Granting ALL
is equivalent to granting the following permissions.
Securable | Permissions |
---|---|
Database | BACKUP DATABASE , BACKUP LOG , CREATE DATABASE , CREATE DEFAULT , CREATE FUNCTION , CREATE PROCEDURE , CREATE RULE , CREATE TABLE , and CREATE VIEW |
Scalar function | EXECUTE and REFERENCES |
Table-valued function | DELETE , INSERT , REFERENCES , SELECT , and UPDATE |
Stored procedure | EXECUTE |
Table | DELETE , INSERT , REFERENCES , SELECT , and UPDATE |
View | DELETE , INSERT , REFERENCES , SELECT , and UPDATE |
PRIVILEGES
Included for ISO compliance. Doesn't change the behavior of ALL
.
permission
The name of a permission. The valid mappings of permissions to securables are described in the following sections.
column
Specifies the name of a column in a table on which permissions are being granted. The parentheses (
and )
are required.
class
Specifies the class of the securable on which the permission is being granted. The scope qualifier ::
is required.
securable
Specifies the securable on which the permission is being granted.
TO principal
The name of a principal. The principals to which permissions on a securable can be granted vary, depending on the securable. See the following sections for valid combinations.
GRANT OPTION
Indicates that the grantee will also be given the ability to grant the specified permission to other principals.
AS principal
Use the AS <principal>
clause to indicate that the principal recorded as the grantor of the permission should be a principal other than the person executing the statement. For example, presume that user Mary
has a principal_id
of 12
, and user Raul
is principal 15
. Mary executes GRANT SELECT ON OBJECT::X TO Steven WITH GRANT OPTION AS Raul;
Now the sys.database_permissions
table indicates that the grantor_principal_id
was 15
(Raul
) even though the statement was actually executed by user 12
(Mary
).
Using the AS
clause is typically not recommended unless you need to explicitly define the permission chain. For more information, see Summary of the Permission Check Algorithm.
The use of AS
in this statement doesn't imply the ability to impersonate another user.
Remarks
The full syntax of the GRANT
statement is complex. The previous syntax diagram was simplified to draw attention to its structure. Complete syntax for granting permissions on specific securables is described in the articles listed later in this article.
The REVOKE
statement can be used to remove granted permissions, and the DENY
statement can be used to prevent a principal from gaining a specific permission through a GRANT
.
Granting a permission removes DENY
or REVOKE
of that permission on the specified securable. If the same permission is denied at a higher scope that contains the securable, the DENY
takes precedence. But revoking the granted permission at a higher scope doesn't take precedence.
Database-level permissions are granted within the scope of the specified database. If a user needs permissions to objects in another database, create the user account in the other database, or grant the user account access to the other database, as well as the current database.
Caution
A table-level DENY
does not take precedence over a column-level GRANT
. This inconsistency in the permissions hierarchy has been preserved for the sake of backward compatibility. It will be removed in a future release.
The sp_helprotect
system stored procedure reports permissions on a database-level securable.
In Microsoft Fabric, CREATE USER
can't be explicitly executed currently. When GRANT
or DENY
is executed, the user is created automatically.
WITH GRANT OPTION
The GRANT ... WITH GRANT OPTION
specifies that the security principal receiving the permission is given the ability to grant the specified permission to other security accounts. When the principal that receives the permission is a role or a Windows group, the AS
clause must be used when the object permission needs to be further granted to users who aren't members of the group or role. Because only a user, rather than a group or role, can execute a GRANT
statement, a specific member of the group or role must use the AS
clause to explicitly invoke the role or group membership when granting the permission. The following example shows how the WITH GRANT OPTION
is used when granted to a role or Windows group.
-- Execute the following as a database owner
GRANT EXECUTE ON TestProc TO TesterRole WITH GRANT OPTION;
EXEC sp_addrolemember TesterRole, User1;
-- Execute the following as User1
-- The following fails because User1 does not have the permission as the User1
GRANT EXECUTE ON TestProc TO User2;
-- The following succeeds because User1 invokes the TesterRole membership
GRANT EXECUTE ON TestProc TO User2 AS TesterRole;
Chart of SQL Server permissions
For a poster sized chart of all Database Engine permissions in PDF format, see https://aka.ms/sql-permissions-poster.
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. If using the AS
option, additional requirements apply. See the securable-specific article for details.
Object owners can grant permissions on the objects they own. Principals with CONTROL
permission on a securable can grant permission on that securable.
Grantees of CONTROL SERVER
permission, such as members of the sysadmin fixed server role, can grant any permission on any securable in the server. 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. Grantees of CONTROL
permission on a schema can grant any permission on any object within the schema.
Examples
The following table lists the securables and the articles that describe the securable-specific syntax.