Skip to main content

SHOW_GRANTS

Introduced or updated: v1.2.704

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>')

Configuring enable_expand_roles Setting

The enable_expand_roles setting controls whether the SHOW_GRANTS function expands role inheritance when displaying privileges.

  • enable_expand_roles=1 (default):

    • SHOW_GRANTS recursively expands inherited privileges, meaning that if a role has been granted another role, it will display all the inherited privileges.
    • Users will also see all privileges granted through their assigned roles.
  • enable_expand_roles=0:

    • SHOW_GRANTS only displays privileges that are directly assigned to the specified role or user.
    • However, the result will still include GRANT ROLE statements to indicate role inheritance.

For example, role a has the SELECT privilege on t1, and role b has the SELECT privilege on t2:

SELECT grants FROM show_grants('role', 'a') ORDER BY object_id;

┌──────────────────────────────────────────────────────┐
│ grants │
├──────────────────────────────────────────────────────┤
GRANT SELECT ON 'default'.'default'.'t1' TO ROLE `a`
└──────────────────────────────────────────────────────┘

SELECT grants FROM show_grants('role', 'b') ORDER BY object_id;

┌──────────────────────────────────────────────────────┐
│ grants │
├──────────────────────────────────────────────────────┤
GRANT SELECT ON 'default'.'default'.'t2' TO ROLE `b`
└──────────────────────────────────────────────────────┘

If you grant role b to role a and check the grants on role a again, you can see than the SELECT privilege on t2 is now included in role a:

GRANT ROLE b TO ROLE a;
SELECT grants FROM show_grants('role', 'a') ORDER BY object_id;

┌──────────────────────────────────────────────────────┐
│ grants │
├──────────────────────────────────────────────────────┤
GRANT SELECT ON 'default'.'default'.'t1' TO ROLE `a`
GRANT SELECT ON 'default'.'default'.'t2' TO ROLE `a`
└──────────────────────────────────────────────────────┘

If you set enable_expand_roles to 0 and check the grants on role a again, the result will show the GRANT ROLE statement instead of listing the specific privileges inherited from role b:

SET enable_expand_roles=0;
SELECT grants FROM show_grants('role', 'a') ORDER BY object_id;

┌──────────────────────────────────────────────────────┐
│ grants │
├──────────────────────────────────────────────────────┤
GRANT SELECT ON 'default'.'default'.'t1' TO ROLE `a`
GRANT ROLE b to ROLE `a`
GRANT ROLE public to ROLE `a`
└──────────────────────────────────────────────────────┘

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 │ │
└─────────────────────────────────────────────────────────────────────────────────────┘
Explore Databend Cloud for FREE
Low-cost
Fast Analytics
Easy Data Ingestion
Elastic Scaling
Try it today