Skip to main content

SHOW_GRANTS

Introduced or updated: v1.2.487

Lists privileges explicitly granted to a user, to a role, or on a specific object.

See also: SHOW GRANTS

Syntax

SHOW_GRANTS('role', '<role_name>')
SHOW_GRANTS('user', '<user_name>')
SHOW_GRANTS('stage', '<stage_name>')
SHOW_GRANTS('udf', '<udf_name>')
SHOW_GRANTS('table', '<table_name>', '<catalog_name>', '<db_name>')
SHOW_GRANTS('database', '<db_name>', '<catalog_name>')

Examples

This example illustrates how to list privileges granted to a user, a role, and on a specific object.

-- Create a new user
CREATE USER 'user1' IDENTIFIED BY 'password';

-- Create a new role
CREATE ROLE analyst;

-- Grant the analyst role to the user
GRANT ROLE analyst TO 'user1';

-- Create a stage
CREATE STAGE my_stage;

-- Grant privileges on the stage to the role
GRANT READ ON STAGE my_stage TO ROLE analyst;

-- List privileges granted to the user
SELECT * FROM SHOW_GRANTS('user', 'user1');

┌───────────────────────────────────────────────────────────────────────────────────────────────────────────────┐
privileges │ object_name │ object_id │ grant_to │ name │ grants │
├────────────┼─────────────┼──────────────────┼──────────┼────────┼─────────────────────────────────────────────┤
Read │ my_stage │ NULLUSER │ user1 │ GRANT Read ON STAGE my_stage TO 'user1'@'%'
└───────────────────────────────────────────────────────────────────────────────────────────────────────────────┘

-- List privileges granted to the role
SELECT * FROM SHOW_GRANTS('role', 'analyst');

┌───────────────────────────────────────────────────────────────────────────────────────────────────────────────────┐
privileges │ object_name │ object_id │ grant_to │ name │ grants │
├────────────┼─────────────┼──────────────────┼──────────┼─────────┼────────────────────────────────────────────────┤
Read │ my_stage │ NULL │ ROLE │ analyst │ GRANT Read ON STAGE my_stage TO ROLE `analyst`
└───────────────────────────────────────────────────────────────────────────────────────────────────────────────────┘

-- List privileges granted on the stage
SELECT * FROM SHOW_GRANTS('stage', 'my_stage');

┌─────────────────────────────────────────────────────────────────────────────────────┐
privileges │ object_name │ object_id │ grant_to │ name │ grants │
├────────────┼─────────────┼──────────────────┼──────────┼─────────┼──────────────────┤
Read │ my_stage │ NULL │ ROLE │ analyst │ │
└─────────────────────────────────────────────────────────────────────────────────────┘
Did this page help you?
Yes
No
Explore Databend Cloud for FREE
Low-cost
Fast Analytics
Easy Data Ingestion
Elastic Scaling
Try it today