The list of all the queries

Perhaps excessive privileges to use views

Query goal: Find non-SELECT privileges to use views (for others than the owner of the view). Perhaps there should be only the privilege to make queries (SELECT statements based on the views) and data modification takes place by using routines. REFERENCES and TRIGGER privileges are definitely not needed.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Medium (Medium number of false-positive results)
Query license: MIT License
Fixing suggestion: Revoke the excess privileges.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

SELECT tp.grantee, tp.table_schema AS view_schema, tp.table_name AS view_name, tp.privilege_type
FROM information_schema.table_privileges AS tp INNER JOIN information_schema.tables AS t
ON t.table_schema=tp.table_schema AND t.table_name=tp.table_name
WHERE t.table_type='VIEW' AND tp.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 tp.privilege_type<>'SELECT'
AND grantee <> ALL (SELECT viewowner
FROM pg_catalog.pg_views AS pv
WHERE pv.schemaname=tp.table_schema AND pv.viewname=tp.table_name)
ORDER BY grantee, tp.table_schema, tp.table_name;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
SELECT format('REVOKE %1$s ON TABLE %2$I.%3$I FROM %4$I;', tp.privilege_type, tp.table_schema, tp.table_name, tp.grantee) AS statements
FROM information_schema.table_privileges AS tp INNER JOIN information_schema.tables AS t
ON t.table_schema=tp.table_schema AND t.table_name=tp.table_name
WHERE t.table_type='VIEW' AND tp.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 tp.privilege_type<>'SELECT'
AND grantee <> ALL (SELECT viewowner
FROM pg_catalog.pg_views AS pv
WHERE pv.schemaname=tp.table_schema AND pv.viewname=tp.table_name)
ORDER BY grantee, tp.table_schema, tp.table_name;
Revoke the privilege.

Collections where the query belongs to

Collection nameCollection description
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 where the query belongs to

Category nameCategory description
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.

Reference materials for further reading

Reference
https://www.postgresql.org/docs/current/ddl-priv.html
https://en.wikipedia.org/wiki/Principle_of_least_privilege

The list of all the queries