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| 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_
-
USAGEprivilege is given by default when a user is created.It is a synonym for “no privileges”. All privileges must be given separately using the GRANTcommand.memsql> CREATE DATABASE db1; Query OK, 1 row affected (1.33 sec) memsql> CREATE USER test; Query OK, 0 rows affected (0.01 sec) memsql> SHOW GRANTS FOR test; +----------------------------------+ | Grants for test@% | +----------------------------------+ | GRANT USAGE ON *.* TO 'test'@'%' | +----------------------------------+ 1 row in set (0.00 sec) memsql> exit $ memsql -u test Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 4 Server version: 5.7.32-debug SingleStoreDB source distribution (compatible; MySQL Enterprise & MySQL Commercial) Copyright (c) 2000, 2024, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. memsql> SHOW DATABASES; +--------------------+ | Database | +--------------------+ | information_schema | +--------------------+ 1 row in set (0.00 sec) memsql> USE db1; ERROR 1044 (42000): Access denied for user 'test'@'%' to database 'db1' memsql> -
*.- 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.
REQUIRE: SSL option ensures that the user connects via SSL.NONE specifies that SSL will not be required for the connection.
Remarks
-
The
GRANTcommand creates a new user if the specified username does not exist and if the engine variablesql_value doesn’t containmode NO_.AUTO_ CREATE_ USER -
The SHOW USERS command requires
*.privileges on all databases to view all users in the cluster.* GRANT ALL ON *.* to <user>; -
A user with the
SUPER(admin) 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 GRANTcommand.
-
-
Refer to the Permission Matrix for the required permissions.
-
USAGEprivilege 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(admin),CREATE USER,SYSTEM_,VARIABLES_ ADMIN CLUSTER,CREATE POOL, andDROP POOLare global privileges.They can be granted only on *.and not on specific databases or tables.* -
The
WITH GRANT OPTIONclause grants theGRANT OPTIONprivilege, 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 OPTIONclause 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 OPTIONprivilege may be able to combine their privileges.A user with both the
GRANT OPTIONandSUPERprivileges can grant any privilege to the users (including themselves) within a scoped database. -
The
EXECUTEpermission 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 SELECTqueries.Similarly, a user with EXECUTEprivileges for a stored procedure can run the SP using theCALLorECHOstatements. -
The
CREATE ROUTINEprivilege allows a user to create an extensibility object (for example, a UDF, UDAF, TVF, or SP). -
The
ALTER ROUTINEprivilege allows a user to replace or delete an extensibility object (for example, a UDF, UDAF, TVF, or SP). -
GRANTsyntax for the following authentication users as follows: -
This command causes implicit commits.
Refer to COMMIT for more information. -
This command can be run on any SingleStore node.
For more information, see the Cluster Management Commands. -
The
GRANTcommand 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 EXECUTE ON dbname.procname TO username;
Related Topics
Last modified: October 22, 2025