SHOW DATABASE ROLES¶
Lists all the database roles in the specified database.
Important
A user with any active role that has been granted any privilege on the active database (e.g. USAGE) can list the database roles in the database. However, this does not necessarily mean the role allows users to use the database roles to perform SQL actions. To use a database role, it must first be granted to an account role that users can activate in a user session, or to an account role lower in a hierarchy.
This is a part of Discretionary Access Control and Role-Based Access Control. For more information, see Overview of Access Control.
Tip
You can also use the Snowflake REST APIs to perform this operation. For information, see List database roles (REST endpoint reference).
- See also:
SHOW GRANTS , CREATE DATABASE ROLE , ALTER DATABASE ROLE , DROP DATABASE ROLE
Syntax¶
SHOW DATABASE ROLES IN DATABASE <name>
[ LIMIT <rows> [ FROM '<name_string>' ] ]
Required parameters¶
name
Specifies the name of the database.
The command returns an error if you do not specify the name identifier.
Optional parameters¶
LIMIT rows [ FROM 'name_string' ]
Optionally limits the maximum number of rows returned, while also enabling “pagination” of the results. The actual number of rows returned might be less than the specified limit. For example, the number of existing objects is less than the specified limit.
The optional
FROM 'name_string'
subclause effectively serves as a “cursor” for the results. This enables fetching the specified number of rows following the first row whose object name matches the specified string:The string must be enclosed in single quotes and is case-sensitive.
The string does not have to include the full object name; partial names are supported.
Default: No value (no limit is applied to the output)
Note
For SHOW commands that support both the
FROM 'name_string'
andSTARTS WITH 'name_string'
clauses, you can combine both of these clauses in the same statement. However, both conditions must be met or they cancel out each other and no results are returned.In addition, objects are returned in lexicographic order by name, so
FROM 'name_string'
only returns rows with a higher lexicographic value than the rows returned bySTARTS WITH 'name_string'
.For example:
... STARTS WITH 'A' LIMIT ... FROM 'B'
would return no results.... STARTS WITH 'B' LIMIT ... FROM 'A'
would return no results.... STARTS WITH 'A' LIMIT ... FROM 'AB'
would return results (if any rows match the input strings).
Usage notes¶
This command only supports showing database roles in a specific database.
You cannot use this command to show database roles in the account.
The command does not require a running warehouse to execute.
To post-process the output of this command, you can use the RESULT_SCAN function, which treats the output as a table that can be queried.
Example¶
Return up to ten database roles in the database named mydb
after the first database role named db_role2
:
SHOW DATABASE ROLES IN DATABASE mydb LIMIT 10 FROM 'db_role2';