The list of all the queries

Insufficient view privileges

Query goal: You must give privileges to use views to the users/roles that correspond to applications
Notes about the query: The query returns a row if there are less than three views that usage right is granted to some non-superuser. It could be that the user, which corresponds to an application, has some but not all the necessary privileges in the database. In this case the query will give false negative answer. The number in the condition (3) is an example and could be changed. The condition in the query ensures that if the requirement is not fulfilled, then the query returns one row, otherwise it does not return a row. The result is achieved by using a PostgreSQL feature that permits SELECT statements without the FROM clause.
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
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH privs AS (SELECT DISTINCT tp.grantee, tp.table_schema, tp.table_name
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 grantee <> ALL (SELECT viewowner
FROM pg_catalog.pg_views AS pv
WHERE pv.schemaname=tp.table_schema AND pv.viewname=tp.table_name))
SELECT 'You must give rights to use views to the users/roles that correspond to applications' As comment
WHERE (SELECT Count(*) AS cnt FROM privs)<3;

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

The list of all the queries