grant

Description

Assigns permissions to users or to user-defined roles. Assigns roles to users or system or user-defined roles.

Syntax

To grant permission to access database objects:

grant {all [privileges]| permission_list} 
	on { table_name [(column_list)]
		| view_name[(column_list)] 
		| stored_procedure_name}
	to {public | name_list | role_name}
	[with grant option]

To grant permission to execute certain commands:

grant {all [privileges] | command_list} 
	to {public | name_list | role_name}

To grant a role to a user or a role:

grant {role role_granted [, role_granted ...]}
	to grantee [, grantee...]

Parameters

all

when used to assign permission to access database objects (the first syntax format), all specifies that all permissions applicable to the specified object are granted. All object owners can use grant all with an object name to grant permissions on their own objects.

Only a System Administrator or the Database Owner can assign permission to create database objects (the second syntax format). When used by a System Administrator, grant all assigns all create permissions (create database, create default, create procedure, create rule, create table, and create view). When the Database Owner uses grant all, Adaptive Server grants all create permissions except create database, and prints an informational message.

Specifying all does not include permission to execute set proxy or set session authorization.

permission_list

is a list of object access permissions granted. If more than one permission is listed, separate them with commas. The following table illustrates the access permissions that can be granted on each type of object:

Object

permission_list can include

Table

select, insert, delete, update, references

View

select, insert, delete, update

Column

select, update, references Column names can be specified in either permission_list or column_list (see Example 2).

Stored procedure

execute

command_list

is a list of commands that the user can execute. If more than one command is listed, separate them with commas. The command list can include create database, create default, create procedure, create rule, create table, create view, set proxy, and set session authorization.

create database permission can be granted only by a System Administrator, and only from within the master database.

Only a System Security Officer can grant users permission to execute set proxy or set session authorization. Granting permission to execute set proxy or set session authorization allows the grantee to impersonate another login in the server. set proxy and set session authorization are identical, except that set session authorization follows the ANSI92 standard, and set proxy is a Transact-SQL extension.

table_name

is the name of the table on which you are granting permissions. The table must be in your current database. Only one object can be listed for each grant statement.

column_list

is a list of columns, separated by commas, to which the permissions apply. If columns are specified, only select, references, and update permissions can be granted.

view_name

is the name of the view on which you are granting permissions. The view must be in your current database. Only one object can be listed for each grant statement.

stored_procedure_name

is the name of the stored procedure on which you are granting permissions. The stored procedure must be in your current database. Only one object can be listed for each grant statement.

public

is all users. For object access permissions, public excludes the object owner. For object creation permissions or set proxy authorizations, public excludes the Database Owner. You cannot grant permissions with grant option to “public” or to other groups or roles.

name_list

is a list of users’ database names and/or group names, separated by commas.

with grant option

allows the users specified in name_list to grant object access permissions to other users. You can grant permissions with grant option only to individual users, not to “public” or to a group or role.

role

grants a role to a user or to a system or user-defined role.

role_granted

is the name of a system or user-defined role that the System Security Officer is granting to a user or a role.

grantee

is the name of a system role, user-defined role, or a user, to whom you are granting a role.

role_name

is the name of a system or user-defined role to which you are granting the permission.

Examples

Example 1

Grants Mary and the “sales” group permission to use the insert and delete commands on the titles table:

grant insert, delete
on titles
to mary, sales

Example 2

Two ways to grant update permission on the price and advance columns of the titles table to “public” (which includes all users):

grant update
on titles (price, advance)
to public

or:

grant update (price, advance)
on titles 
to public

Example 3

Grants Harry and Billy permission to execute either set proxy or set session authorization to impersonate another user in the server:

grant set proxy to harry, billy

Example 4

Grants users with sso_role permission to execute either set proxy or set session authorization to impersonate another user in the server:

grant set session authorization to sso_role

Example 5

Grants users with vip_role the ability to impersonate another user in the server. vip_role must be a role defined by a System Security Officer with the create role command:

grant set proxy to vip_role

Example 6

Grants Mary and John permission to use the create database and create table commands. Because create database permission is being granted, this command can be executed only by a System Administrator within the master database. Mary and John’s create table permission applies only to the master database:

grant create database, create table
to mary, john

Example 7

Grants complete access permissions on the titles table to all users:

grant all on titles 
to public

Example 8

Grants all object creation permissions in the current database to all users. If this command is executed by a System Administrator from the master database, it includes create database permission:

grant all
to public

Example 9

Gives Mary permission to use the update command on the authors table and to grant that permission to others:

grant update on authors
to mary
with grant option

Example 10

Gives Bob permission to use the select and update commands on the price column of the titles table and to grant that permission to others:

grant select, update on titles(price)
to bob
with grant option

Example 11

Grants permission to execute the new_sproc stored procedure to all System Security Officers:

grant execute on new_sproc
to sso_role

Example 12

Grants James permission to create a referential integrity constraint on another table that refers to the price column of the titles table:

grant references on titles(price)
to james

Example 13

Grants the role “specialist”, with all its permissions and privileges, to the role “doctor”:

grant role specialist_role to doctor_role

Example 14

Grants the role “doctor” to Mary:

grant role doctor_role to mary

Usage


grant all object creation permissions


grant with grant option rules


Granting proxies and session authorizations


Granting permission to roles


Users and user groups

Standards

SQL92 – Compliance level: Entry-level compliant.

Granting permissions to groups and granting set proxy are Transact-SQL extensions. Granting set session authorization (identical in function to set proxy) follows the ANSI standard.

Permissions

Database object access grant permission for database objects defaults to object owners. An object owner can grant permission to other users on his or her own database objects.

Command execution Only a System Administrator can grant create database permission, and only from the master database. Only a System Security Officer can grant create trigger permission.

Proxy and session authorization Only a System Security Officer can grant set proxy or set session authorization, and only from the master database.

Roles You can grant roles only from the master database. Only a System Security Officer can grant sso_role, oper_role or a user-defined role to a user or a role. Only System Administrators can grant sa_role to a user or a role. Only a user who has both sa_role and sso_role can grant a role which includes sa_role.

See also

Catalog stored procedures sp_column_privileges

Commands revoke, setuser, set

Functions proc_role

System procedures sp_addgroup, sp_adduser, sp_changedbowner, sp_changegroup, sp_dropgroup, sp_dropuser, sp_helpgroup, sp_helprotect, sp_helpuser, sp_role