Re: "grant usage on schema" confers the ability to execute all user-defined functions in that schema, with needing to grant "execute"

From: Adrian Klaver <adrian(dot)klaver(at)aklaver(dot)com>
To: Bryn Llewellyn <bryn(at)yugabyte(dot)com>, "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com>, Tom Lane PostgreSQL <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: jeremy(at)musicsmith(dot)net, pgsql-general list <pgsql-general(at)lists(dot)postgresql(dot)org>
Subject: Re: "grant usage on schema" confers the ability to execute all user-defined functions in that schema, with needing to grant "execute"
Date: 2022-02-11 23:48:29
Message-ID: 613f1225-26ae-6772-c5da-1cb725674e4f@aklaver.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On 2/11/22 15:14, Bryn Llewellyn wrote:
>> /david(dot)g(dot)johnston(at)gmail(dot)com <mailto:david(dot)g(dot)johnston(at)gmail(dot)com> wrote:/
>>

> I looked at Chapter 52, "System Catalogs" at
> https://www.postgresql.org/docs/current/catalogs.html
> <https://www.postgresql.org/docs/current/catalogs.html>. It lists 97
> relations. I'll have to defer reading about every one of these to
> another day. I searched the page for likely names looking for ones with
> "priv" and "rol". There's just a small number of hits. I drilled down on
> these. But none seemed to help finding out which objects, of which
> kinds, have which privileges (or roles) granted to which grantees.
>
> Which catalog relations are sufficient to support a query that lists
> out, for example, every user-defined function and procedure with its (at
> least first-level) grantees?

Tip if you do:

psql -d test -U postgres -h localhost -E

the -E will get you the queries for the \ meta-commands.

So:

\df+ tag_changeset_fnc

Yields:

SELECT n.nspname as "Schema",
p.proname as "Name",
pg_catalog.pg_get_function_result(p.oid) as "Result data type",
pg_catalog.pg_get_function_arguments(p.oid) as "Argument data types",
CASE p.prokind
WHEN 'a' THEN 'agg'
WHEN 'w' THEN 'window'
WHEN 'p' THEN 'proc'
ELSE 'func'
END as "Type",
CASE
WHEN p.provolatile = 'i' THEN 'immutable'
WHEN p.provolatile = 's' THEN 'stable'
WHEN p.provolatile = 'v' THEN 'volatile'
END as "Volatility",
CASE
WHEN p.proparallel = 'r' THEN 'restricted'
WHEN p.proparallel = 's' THEN 'safe'
WHEN p.proparallel = 'u' THEN 'unsafe'
END as "Parallel",
pg_catalog.pg_get_userbyid(p.proowner) as "Owner",
CASE WHEN prosecdef THEN 'definer' ELSE 'invoker' END AS "Security",
pg_catalog.array_to_string(p.proacl, E'\n') AS "Access privileges",
l.lanname as "Language",
p.prosrc as "Source code",
pg_catalog.obj_description(p.oid, 'pg_proc') as "Description"
FROM pg_catalog.pg_proc p
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace
LEFT JOIN pg_catalog.pg_language l ON l.oid = p.prolang
WHERE p.proname OPERATOR(pg_catalog.~) '^(tag_changeset_fnc)$' COLLATE
pg_catalog.default
AND pg_catalog.pg_function_is_visible(p.oid)
ORDER BY 1, 2, 4;

The parts you would be interested in are "Owner", "Security" and "Access
privileges". You could modify the query to slim the results down some.

--
Adrian Klaver
adrian(dot)klaver(at)aklaver(dot)com

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Adrian Klaver 2022-02-12 00:08:32 Re: "grant usage on schema" confers the ability to execute all user-defined functions in that schema, with needing to grant "execute"
Previous Message Bryn Llewellyn 2022-02-11 23:14:39 Re: "grant usage on schema" confers the ability to execute all user-defined functions in that schema, with needing to grant "execute"