The list of all the queries

Views without security barrier

Query goal: Find views that do not have the security barrier option.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: High (Few or no false-positive results)
Query license: MIT License
Fixing suggestion: Alter the view by adding the security_barrier option.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

SELECT 
  pg_namespace.nspname AS view_schema, 
  pg_class.relname AS view_name 
FROM 
  pg_catalog.pg_class, 
  pg_catalog.pg_namespace
WHERE pg_catalog.pg_class.relnamespace=pg_catalog.pg_namespace.oid 
AND relkind='v'
AND nspname NOT IN (SELECT schema_name
FROM information_schema.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND (('security_barrier=true'<>ALL(pg_catalog.pg_class.reloptions)) OR pg_catalog.pg_class.reloptions IS NULL)
ORDER BY view_schema, view_name;

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

SQL queryDescription
WITH missing_barrier AS (SELECT 
  pg_namespace.nspname AS view_schema, 
  pg_class.relname AS view_name 
FROM 
  pg_catalog.pg_class, 
  pg_catalog.pg_namespace
WHERE pg_catalog.pg_class.relnamespace=pg_catalog.pg_namespace.oid 
AND relkind='v'
AND nspname NOT IN (SELECT schema_name
FROM information_schema.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND (('security_barrier=true'<>ALL(pg_catalog.pg_class.reloptions)) OR pg_catalog.pg_class.reloptions IS NULL))
SELECT format('ALTER VIEW %1$I.%2$I SET (security_barrier);', view_schema, view_name) AS statements
FROM missing_barrier 
ORDER BY view_schema, view_name;
Alter the view.

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.2ndquadrant.com/en/blog/how-do-postgresql-security_barrier-views-work/

The list of all the queries