Re: role to access all information_schema.*? - Mailing list pgsql-admin

From Laurenz Albe
Subject Re: role to access all information_schema.*?
Date
Msg-id 8b5a7c1d55c1c938cb8c39da2cf29711c6dc9247.camel@cybertec.at
Whole thread Raw
In response to Re: role to access all information_schema.*?  (Ruben Laguna <ruben.laguna@gmail.com>)
List pgsql-admin
On Tue, 2025-10-07 at 22:59 +0200, Ruben Laguna wrote:
> Do you know what the standard says exactly, does it outright bans using any
> special means like having (pg_metadata_viewr or pg_read_information_schema,
> etc). as "access privilege"?

Yes, that would be ISO/IEC 9075-11.  They define for example
information_schema.tables as

CREATE VIEW TABLES AS
SELECT TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, TABLE_TYPE,
SELF_REFERENCING_COLUMN_NAME, REFERENCE_GENERATION,
USER_DEFINED_TYPE_CATALOG, USER_DEFINED_TYPE_SCHEMA,
USER_DEFINED_TYPE_NAME, IS_INSERTABLE_INTO, IS_TYPED,
COMMIT_ACTION
FROM DEFINITION_SCHEMA.TABLES
WHERE ( TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME ) IN
( SELECT TP.TABLE_CATALOG, TP.TABLE_SCHEMA, TP.TABLE_NAME
FROM DEFINITION_SCHEMA.TABLE_PRIVILEGES AS TP
WHERE ( TP.GRANTEE IN
( 'PUBLIC', CURRENT_USER )
OR
GRANTEE IN
( SELECT ROLE_NAME
FROM ENABLED_ROLES ) )
UNION
SELECT CP.TABLE_CATALOG, CP.TABLE_SCHEMA, CP.TABLE_NAME
FROM DEFINITION_SCHEMA.COLUMN_PRIVILEGES AS CP
WHERE ( CP.GRANTEE IN
( 'PUBLIC', CURRENT_USER )
OR
CP.GRANTEE IN
( SELECT ROLE_NAME
FROM ENABLED_ROLES ) ) )
AND
TABLE_CATALOG
= ( SELECT CATALOG_NAME
FROM INFORMATION_SCHEMA_CATALOG_NAME );

> Do you think it's hopeless to propose this in pgsql-hackers?

I agree with Tom, there is little hope.

Yours,
Laurenz Albe



pgsql-admin by date:

Previous
From: Daulat
Date:
Subject: Tools for Comparing Objects Between Two PostgreSQL Databases
Next
From: Laurenz Albe
Date:
Subject: Re: Dropping index from large, partitioned table