From 6f120d7906eec9644d0670499fbcea1dbfe73031 Mon Sep 17 00:00:00 2001
From: Joel Jakobsson <github@compiler.org>
Date: Fri, 21 Jun 2024 08:38:19 +0200
Subject: [PATCH 1/2] Add pg_get_acl() function to get the ACL for a database
 object.

This SQL-callable function returns the Access Control List (ACL)
for a database object, specified by catalog OID and object OID.

Discussion: https://postgr.es/m/80b16434-b9b1-4c3d-8f28-569f21c2c102@app.fastmail.com
Related Discussion: https://postgr.es/m/261def6b-226e-4238-b7eb-ff240cb9c2c9@www.fastmail.com
---
 doc/src/sgml/func.sgml                   | 26 +++++++++++++
 src/backend/catalog/objectaddress.c      | 47 ++++++++++++++++++++++++
 src/include/catalog/pg_proc.dat          |  6 +++
 src/test/regress/expected/privileges.out | 12 ++++++
 src/test/regress/sql/privileges.sql      |  2 +
 5 files changed, 93 insertions(+)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 2609269610..3412228f97 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -26686,6 +26686,32 @@ SELECT currval(pg_get_serial_sequence('sometable', 'id'));
         Undefined objects are identified with <literal>NULL</literal> values.
        </para></entry>
       </row>
+
+      <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 Access Control List (ACL) for a database object,
+        specified by catalog OID and object OID.
+        This function is useful for retrieving and inspecting the privileges associated with database objects.
+        This function returns NULL values for undefined objects.
+        Example, showing explicitly granted privileges on objects in current database:
+<programlisting>
+SELECT
+    (pg_identify_object(s.classid,s.objid,s.objsubid)).*,
+    pg_catalog.pg_get_acl(s.classid,s.objid)
+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';
+</programlisting>
+       </para></entry>
+      </row>
      </tbody>
     </tgroup>
    </table>
diff --git a/src/backend/catalog/objectaddress.c b/src/backend/catalog/objectaddress.c
index 7b536ac6fd..5206e29df1 100644
--- a/src/backend/catalog/objectaddress.c
+++ b/src/backend/catalog/objectaddress.c
@@ -4362,6 +4362,53 @@ pg_identify_object_as_address(PG_FUNCTION_ARGS)
 	PG_RETURN_DATUM(HeapTupleGetDatum(htup));
 }
 
+/*
+ * SQL-level callable function to obtain the Access Control List (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_oid;
+	AttrNumber	Anum_acl;
+
+	/* for "pinned" items in pg_depend, return null */
+	if (!OidIsValid(classId) && !OidIsValid(objectId))
+		PG_RETURN_NULL();
+
+	catalogId = (classId == LargeObjectRelationId) ? LargeObjectMetadataRelationId : classId;
+	Anum_oid = get_object_attnum_oid(catalogId);
+	Anum_acl = get_object_attnum_acl(catalogId);
+
+	if (Anum_acl != InvalidAttrNumber)
+	{
+		Relation rel;
+		HeapTuple tup;
+		Datum datum;
+		bool isnull;
+
+		rel = table_open(catalogId, AccessShareLock);
+
+		tup = get_catalog_object_by_oid(rel, Anum_oid, 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_DATUM(datum);
+	}
+
+	PG_RETURN_NULL();
+}
+
 /*
  * Return a palloc'ed string that describes the type of object that the
  * passed address is for.
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 6a5476d3c4..5ab9b11b47 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -6362,6 +6362,12 @@
   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',
diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out
index eb4b762ea1..f82338354e 100644
--- a/src/test/regress/expected/privileges.out
+++ b/src/test/regress/expected/privileges.out
@@ -213,10 +213,22 @@ 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 pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid);
+                                                                                                    pg_get_acl                                                                                                    
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ {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}
+(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;
diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql
index eeb4c00292..eddb597f87 100644
--- a/src/test/regress/sql/privileges.sql
+++ b/src/test/regress/sql/privileges.sql
@@ -183,10 +183,12 @@ 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 pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid);
 
 GRANT TRUNCATE ON atest2 TO regress_priv_user4 GRANTED BY regress_priv_user5;  -- error
 
-- 
2.45.1

