From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Pavel Luzanov <p(dot)luzanov(at)postgrespro(dot)ru> |
Cc: | pgsql-hackers <pgsql-hackers(at)postgresql(dot)org>, Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com> |
Subject: | Re: multiple membership grants and information_schema.applicable_roles |
Date: | 2023-07-23 20:03:36 |
Message-ID: | 1406968.1690142616@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-hackers |
Pavel Luzanov <p(dot)luzanov(at)postgrespro(dot)ru> writes:
> The application_roles view shows duplicates:
> postgres(at)postgres(17.0)=# SELECT * FROM
> information_schema.applicable_roles WHERE grantee = 'alice';
> grantee | role_name | is_grantable
> ---------+-----------+--------------
> alice | bob | NO
> alice | bob | YES
> (2 rows)
AFAICT this is also possible with the SQL standard's definition
of this view, so I don't see a bug here:
CREATE RECURSIVE VIEW APPLICABLE_ROLES ( GRANTEE, ROLE_NAME, IS_GRANTABLE ) AS
( ( SELECT GRANTEE, ROLE_NAME, IS_GRANTABLE
FROM DEFINITION_SCHEMA.ROLE_AUTHORIZATION_DESCRIPTORS
WHERE ( GRANTEE IN
( CURRENT_USER, 'PUBLIC' )
OR
GRANTEE IN
( SELECT ROLE_NAME
FROM ENABLED_ROLES ) ) )
UNION
( SELECT RAD.GRANTEE, RAD.ROLE_NAME, RAD.IS_GRANTABLE
FROM DEFINITION_SCHEMA.ROLE_AUTHORIZATION_DESCRIPTORS RAD
JOIN
APPLICABLE_ROLES R
ON
RAD.GRANTEE = R.ROLE_NAME ) );
The UNION would remove rows only when they are duplicates across all
three columns.
I do see what seems like a different issue: the standard appears to expect
that indirect role grants should also be shown (via the recursive CTE),
and we are not doing that.
regards, tom lane
From | Date | Subject | |
---|---|---|---|
Next Message | Anton A. Melnikov | 2023-07-23 20:21:47 | [BUG] Crash on pgbench initialization. |
Previous Message | Peter Geoghegan | 2023-07-23 19:56:11 | Re: Use of additional index columns in rows filtering |