GRANT
On this page
Grants the specified privileges to an existing user.
All of the privileges and their scope (global, database, table, etc.
Syntax
GRANT priv_type [, priv_type [ ... ]] ON priv_levelTO user_or_role [, user_or_role [ ... ]][WITH GRANT OPTION][REQUIRE {SSL | NONE}]priv_type:ALL PRIVILEGES| SELECT| INSERT| UPDATE| DELETE| CREATE| DROP| RELOAD| PROCESS| FILE READ| FILE WRITE| INDEX| ALTER| SHOW METADATA| GRANT OPTION| SUPER| CREATE TEMPORARY TABLES| LOCK TABLES| CREATE VIEW| SHOW VIEW| CREATE USER| CLUSTER| ALTER VIEW| DROP VIEW| BACKUP| CREATE DATABASE| DROP DATABASE| CREATE PIPELINE| DROP PIPELINE| ALTER PIPELINE| START PIPELINE| SHOW PIPELINE| EXECUTE| CREATE ROUTINE| ALTER ROUTINE| SHOW ROUTINE| CREATE POOL| DROP POOL| CREATE LINK| DROP LINK| SHOW LINKpriv_level:*| *.*| database.*| database.tableuser_or_role:user [, user]| roleuser:'user_name'[@'host_name'] [IDENTIFIED BY 'password']role:ROLE 'role_name'
Arguments
priv_
priv_
-
*
-USAGE
privilege only.See Permissions Matrix for more detailed information on which commands can be executed with minimal USAGE
privilege. -
*.
- Global privileges are administrative or apply to all databases on a given server.* -
database.
- Database privileges apply to all objects in a given database.* -
database.
- Table privileges apply to all columns in a given table in a given database.table
user_@'host_
part is optional.@'%'
will be appended to the user string.'demo-user'
is equivalent to 'demo-user'@'%'
.'%'
wildcard matches any hostname.user
and host_
need not be quoted if they are legal as unquoted identifiers.host_
string contains wildcard characters (such as %
), or a user string contains special characters (such as space or -
) or is a restricted keyword.
Remarks
-
The
GRANT
command creates a new user if the specified username does not exist. -
A user with the
SUPER
permission can perform the following actions:-
Set global variables, run administrative commands, and change passwords for other users.
-
Access all available resource pools.
Permissions for additional resource pools can be given using the GRANT
command.
-
-
Refer to the Permission Matrix for the required permission.
-
USAGE
privilege allows users to connect to the cluster, view some SHOW Commands, and view objects on theinformation_
database.schema -
PROCESS
,FILE READ
,FILE WRITE
,SHOW METADATA
,SUPER
,CREATE USER
,SYSTEM_
,VARIABLES_ ADMIN CLUSTER
,CREATE POOL
, andDROP POOL
are global privileges.They can be granted only on *.
and not on specific databases or tables.* -
The
WITH GRANT OPTION
clause grants theGRANT OPTION
privilege, which allows a user to grant all privileges that the user already has to other users within a scoped database.The privilege_
engine variable must be left on the default valuetransfer_ mode grant_
for theoption WITH GRANT OPTION
clause to work as expected.The GRANT .
and. . WITH GRANT OPTION GRANT GRANT OPTION .
statements are synonymous.. . See Default Mode Permissions Changes for more information. Note: Different users with
GRANT OPTION
privilege may be able to combine their privileges.A user with both the
GRANT OPTION
andSUPER
privileges can grant any privilege to the users (including themselves) within a scoped database. -
The
EXECUTE
permission allows a user to execute an extensibility object.For example, having this permission for UDFs, UDAFs, and TVFs allows the user to run them in SELECT
queries.Similarly, a user with EXECUTE
privileges for a stored procedure can run the SP using theCALL
orECHO
statements. -
The
CREATE ROUTINE
privilege allows a user to create an extensibility object (for example, a UDF, UDAF, TVF, or SP). -
The
ALTER ROUTINE
privilege allows a user to replace or delete an extensibility object (for example, a UDF, UDAF, TVF, or SP). -
GRANT
syntax for the following authentication users as follows: -
This command causes implicit commits.
See COMMIT for more information. -
This command can be run on any SingleStoreDB node.
For more information, see the Node Requirements for SingleStoreDB Commands. -
The
GRANT
command holds a global lock on the cluster until the processing of the command is completed.See Cluster Level Locks for more info.
Examples
The following examples demonstrates how to grant privileges to the existing singlestore_
user:
GRANT ALL PRIVILEGES ON *.* TO 'singlestore_admin' IDENTIFIED BY 'password' WITH GRANT OPTION;
Or
GRANT * ON *.* TO 'singlestore_admin' IDENTIFIED BY 'password' WITH GRANT OPTION;
The following example demonstrates how to grant the specified privileges to all databases to the full_
role.
GRANT BACKUP, RELOAD ON *.* TO ROLE 'full_backup_role';
Note
If you removed ROLE
from the example above, the GRANT
command would apply privileges to the user 'full_
.
The following example demonstrates how to grant EXECUTE
and ALTER ROUTINE
privileges for the stored procedure recStock
to user 'adam'
.
GRANT EXECUTE, ALTER ROUTINE ON db_tmp1.recStock TO 'adam';
The following example demonstrates how to grant permissions for a resource pool p1
to a user u1
:
GRANT USAGE ON RESOURCE POOL p1 to 'u1';
The following example demonstrates how to grant the execute permission for a stored procedure or function:
GRANT EXCUTE ON dbname.procname TO username;
Related Topics
Last modified: August 18, 2023