The list of all the queries

User-defined derived tables

Query goal: Find user-defined views and materialized views. Pay attention to the outer join operations. One should use these if and only if there is a real need for them. Otherwise they just reduce performance. On the other hand, pay attention that outer join is used where it is logically needed.
Notes about the query: In the returned subquery of view/materialized view the query adds line break (br) tag at the beginning of each clause for the better readability in case the query result is displayed in a web browser. LEFT JOIN and RIGHT JOIN keywords are marked with red because quite often outer join is used unnecessarily because INNER JOIN operation would be enough. The query uses (b) tags to mark some of the main clauses in the subquery of the derived table.
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

WITH user_defined_derived_tables AS (SELECT 
views.table_schema, 
views.table_name, 
views.view_definition,
'VIEW' AS table_type
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, definition, 'MATERIALIZED VIEW' AS table_type
FROM pg_catalog.pg_matviews)
SELECT
table_schema,
table_name,
regexp_replace(
regexp_replace(view_definition,'((?<!(LEADING|TRAILING|BOTH)[[:space:]])FROM|ORDER BY|WHERE|GROUP BY|SELECT|HAVING|UNION|EXCEPT|INTERSECT|LIMIT|FETCH FIRST)','<br><b>\1</b>','g'),
'(LEFT JOIN|RIGHT JOIN|CROSS JOIN|FULL JOIN)','<font color=red>\1</font>','g') AS def,
table_type
FROM user_defined_derived_tables
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