Re: how to list privileges on the database object itself via SQL?

From: Erik Wienhold <ewie(at)ewie(dot)name>
To: richard coleman <rcoleman(dot)ascentgl(at)gmail(dot)com>, pgsql-admin(at)lists(dot)postgresql(dot)org
Subject: Re: how to list privileges on the database object itself via SQL?
Date: 2023-04-26 17:17:11
Message-ID: 2058602074.1048315.1682529431551@office.mailbox.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

> On 26/04/2023 18:34 CEST richard coleman <rcoleman(dot)ascentgl(at)gmail(dot)com> wrote:
>
> This might sound like a silly question, but how would I list the privileges
> the various roles have on the database objects themselves?
>
> There appear to be a million ways to list the privileges on various database
> objects; tables, views, foreign tables, etc. but for the life of me there
> doesn't appear to an analogous way to get permissions on the database objects
> themselves.
>
> At the moment all that I've found is:
>
> select has_database_privilege('role','db_name', 'CREATE') as can_create;
> select has_database_privilege('role','db_name', 'CONNECT') as can_connect;
> select has_database_privilege('role','db_name', 'TEMP') as can_temp;
>
> Am I missing something?

If you're interested in specific roles or privileges, then aclexplode is your
friend.

SELECT
datname,
grantor::regrole,
grantee::regrole,
privilege_type,
is_grantable
FROM
pg_database,
aclexplode(datacl)
WHERE
grantee = 'role'::regrole
AND privilege_type IN ('CREATE', 'CONNECT', 'TEMPORARY');

--
Erik

In response to

Responses

Browse pgsql-admin by date

  From Date Subject
Next Message richard coleman 2023-04-26 17:20:14 Re: how to list privileges on the database object itself via SQL?
Previous Message Tom Lane 2023-04-26 16:40:43 Re: how to list privileges on the database object itself via SQL?