Add pg_get_acl() to get the ACL for a database object

This function returns the ACL for a database object, specified by
catalog OID and object OID.  This is useful to be able to
retrieve the ACL associated to an object specified with a
(class_id,objid) couple, similarly to the other functions for object
identification, when joined with pg_depend or pg_shdepend.

Original idea by Álvaro Herrera.

Bump catalog version.

Author: Joel Jacobson
Reviewed-by: Isaac Morland, Michael Paquier, Ranier Vilela
Discussion: https://postgr.es/m/80b16434-b9b1-4c3d-8f28-569f21c2c102@app.fastmail.com
This commit is contained in:
Michael Paquier 2024-07-04 17:09:06 +09:00
parent 3a8a1f3254
commit 4564f1cebd
6 changed files with 130 additions and 1 deletions

View File

@ -26587,6 +26587,21 @@ SELECT currval(pg_get_serial_sequence('sometable', 'id'));
</thead>
<tbody>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>pg_get_acl</primary>
</indexterm>
<function>pg_get_acl</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type> )
<returnvalue>aclitem[]</returnvalue>
</para>
<para>
Returns the <acronym>ACL</acronym> for a database object, specified
by catalog OID and object OID. This function returns
<literal>NULL</literal> values for undefined objects.
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
@ -26700,6 +26715,32 @@ SELECT currval(pg_get_serial_sequence('sometable', 'id'));
</tgroup>
</table>
<para>
<function>pg_get_acl</function> is useful for retrieving and inspecting
the privileges associated with database objects without looking at
specific catalogs. For example, to retrieve all the granted privileges
on objects in the current database:
<programlisting>
postgres=# SELECT
(pg_identify_object(s.classid,s.objid,s.objsubid)).*,
pg_catalog.pg_get_acl(s.classid,s.objid) AS acl
FROM pg_catalog.pg_shdepend AS s
JOIN pg_catalog.pg_database AS d
ON d.datname = current_database() AND
d.oid = s.dbid
JOIN pg_catalog.pg_authid AS a
ON a.oid = s.refobjid AND
s.refclassid = 'pg_authid'::regclass
WHERE s.deptype = 'a';
-[ RECORD 1 ]-----------------------------------------
type | table
schema | public
name | testtab
identity | public.testtab
acl | {postgres=arwdDxtm/postgres,foo=r/postgres}
</programlisting>
</para>
</sect2>
<sect2 id="functions-info-comment">

View File

@ -4362,6 +4362,54 @@ pg_identify_object_as_address(PG_FUNCTION_ARGS)
PG_RETURN_DATUM(HeapTupleGetDatum(htup));
}
/*
* SQL-level callable function to obtain the ACL of a specified object, given
* its catalog OID and object OID.
*/
Datum
pg_get_acl(PG_FUNCTION_ARGS)
{
Oid classId = PG_GETARG_OID(0);
Oid objectId = PG_GETARG_OID(1);
Oid catalogId;
AttrNumber Anum_acl;
Relation rel;
HeapTuple tup;
Datum datum;
bool isnull;
/* for "pinned" items in pg_depend, return null */
if (!OidIsValid(classId) && !OidIsValid(objectId))
PG_RETURN_NULL();
/* for large objects, the catalog to look at is pg_largeobject_metadata */
catalogId = (classId == LargeObjectRelationId) ?
LargeObjectMetadataRelationId : classId;
Anum_acl = get_object_attnum_acl(catalogId);
/* return NULL if no ACL field for this catalog */
if (Anum_acl == InvalidAttrNumber)
PG_RETURN_NULL();
rel = table_open(catalogId, AccessShareLock);
tup = get_catalog_object_by_oid(rel, get_object_attnum_oid(catalogId),
objectId);
if (!HeapTupleIsValid(tup))
{
table_close(rel, AccessShareLock);
PG_RETURN_NULL();
}
datum = heap_getattr(tup, Anum_acl, RelationGetDescr(rel), &isnull);
table_close(rel, AccessShareLock);
if (isnull)
PG_RETURN_NULL();
PG_RETURN_DATUM(datum);
}
/*
* Return a palloc'ed string that describes the type of object that the
* passed address is for.

View File

@ -57,6 +57,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 202407012
#define CATALOG_VERSION_NO 202407041
#endif

View File

@ -6362,6 +6362,11 @@
proname => 'pg_describe_object', provolatile => 's', prorettype => 'text',
proargtypes => 'oid oid int4', prosrc => 'pg_describe_object' },
{ oid => '6347', descr => 'get ACL for SQL object',
proname => 'pg_get_acl', provolatile => 's', prorettype => '_aclitem',
proargtypes => 'oid oid', proargnames => '{classid,objid}',
prosrc => 'pg_get_acl' },
{ oid => '3839',
descr => 'get machine-parseable identification of SQL object',
proname => 'pg_identify_object', provolatile => 's', prorettype => 'record',

View File

@ -213,10 +213,39 @@ SELECT * FROM atest1;
(0 rows)
CREATE TABLE atest2 (col1 varchar(10), col2 boolean);
SELECT pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid);
pg_get_acl
------------
(1 row)
GRANT SELECT ON atest2 TO regress_priv_user2;
GRANT UPDATE ON atest2 TO regress_priv_user3;
GRANT INSERT ON atest2 TO regress_priv_user4 GRANTED BY CURRENT_USER;
GRANT TRUNCATE ON atest2 TO regress_priv_user5 GRANTED BY CURRENT_ROLE;
SELECT unnest(pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid));
unnest
------------------------------------------------
regress_priv_user1=arwdDxtm/regress_priv_user1
regress_priv_user2=r/regress_priv_user1
regress_priv_user3=w/regress_priv_user1
regress_priv_user4=a/regress_priv_user1
regress_priv_user5=D/regress_priv_user1
(5 rows)
-- Invalid inputs
SELECT pg_get_acl('pg_class'::regclass, 0); -- null
pg_get_acl
------------
(1 row)
SELECT pg_get_acl(0, 0); -- null
pg_get_acl
------------
(1 row)
GRANT TRUNCATE ON atest2 TO regress_priv_user4 GRANTED BY regress_priv_user5; -- error
ERROR: grantor must be current user
SET SESSION AUTHORIZATION regress_priv_user2;

View File

@ -183,10 +183,16 @@ GRANT SELECT ON atest1 TO regress_priv_user3, regress_priv_user4;
SELECT * FROM atest1;
CREATE TABLE atest2 (col1 varchar(10), col2 boolean);
SELECT pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid);
GRANT SELECT ON atest2 TO regress_priv_user2;
GRANT UPDATE ON atest2 TO regress_priv_user3;
GRANT INSERT ON atest2 TO regress_priv_user4 GRANTED BY CURRENT_USER;
GRANT TRUNCATE ON atest2 TO regress_priv_user5 GRANTED BY CURRENT_ROLE;
SELECT unnest(pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid));
-- Invalid inputs
SELECT pg_get_acl('pg_class'::regclass, 0); -- null
SELECT pg_get_acl(0, 0); -- null
GRANT TRUNCATE ON atest2 TO regress_priv_user4 GRANTED BY regress_priv_user5; -- error