The list of all the queries

Derived tables with multiple DISTINCT's

Query goal: Find derived tables (views and materialized views) that contain more than one DISTINCT invocation. Make sure that the query is correctly written, including that it does not have unwanted formation of a Cartesian product.
Notes about the query: In the returned subquery of view/materialized view the query replaces each newline character with the line break (br) tag for the better readability in case the query result is displayed in a web browser.
Query type: General (Overview of some aspect of the database.)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

SELECT
table_schema,
table_name,
type,
regexp_replace(view_definition,'[\r\n]','<br>','g') AS view_definition
FROM (SELECT 
views.table_schema, 
views.table_name, 
'VIEW' AS type,
views.view_definition
FROM 
information_schema.views
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)
UNION SELECT schemaname, matviewname, 'MATERIALIZED VIEW' AS type, regexp_replace(definition,'[\r\n]','<br>','g') AS definition
FROM pg_catalog.pg_matviews) AS foo
WHERE view_definition ~*'[[:space:]]distinct[[:space:]].+[[:space:]]distinct[[:space:]]'
ORDER BY table_schema, table_name;

Collections where the query belongs to

Collection nameCollection description
Find problems by overviewQueries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems 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.

The list of all the queries