Re: how to list privileges on the database object itself via SQL? - Mailing list pgsql-admin

From Erik Wienhold
Subject Re: how to list privileges on the database object itself via SQL?
Date
Msg-id 2058602074.1048315.1682529431551@office.mailbox.org
Whole thread Raw
In response to how to list privileges on the database object itself via SQL?  (richard coleman <rcoleman.ascentgl@gmail.com>)
Responses Re: how to list privileges on the database object itself via SQL?
List pgsql-admin
> On 26/04/2023 18:34 CEST richard coleman <rcoleman.ascentgl@gmail.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



pgsql-admin by date:

Previous
From: Tom Lane
Date:
Subject: Re: how to list privileges on the database object itself via SQL?
Next
From: richard coleman
Date:
Subject: Re: how to list privileges on the database object itself via SQL?