Goal You should follow the principle of least privilege and thus not have in your database tables that usage privileges are granted to the pseudo-role PUBLIC, i.e., to all the database users now and in the future.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability High (Few or no false-positive results)
License MIT License
Fixing Suggestion Revoke privileges from PUBLIC.
Data Source INFORMATION_SCHEMA only
SQL Query
SELECT table_schema, table_name, table_type, privilege_type, is_grantable
FROM information_schema.table_privileges INNER JOIN information_schema.tables USING (table_schema, table_name)
WHERE table_schema NOT IN  (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND grantee='PUBLIC'
ORDER BY privilege_type, table_type, table_schema, table_name;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
WITH suspected_privileges AS (SELECT table_schema, table_name, table_type, privilege_type
FROM information_schema.table_privileges INNER JOIN information_schema.tables USING (table_schema, table_name)
WHERE table_schema NOT IN  (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND grantee='PUBLIC')
SELECT format('REVOKE %1$s ON TABLE %2$I.%3$I FROM PUBLIC;', privilege_type, table_schema, table_name)
FROM suspected_privileges
ORDER BY privilege_type, table_type, table_schema, table_name;
Revoke the privileges from PUBLIC.
Collections

This query belongs to the following collections:

NameDescription
Find problems automaticallyQueries, that results point to problems in the database. Each query in the collection produces an initial assessment. However, a human reviewer has the final say as to whether there is a problem or not .
Categories

This query is classified under the following categories:

NameDescription
Derived tablesQueries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
SecurityQueries of this category provide information about the security measures.

Further reading and related materials:

Reference
https://en.wikipedia.org/wiki/Principle_of_least_privilege