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
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.
Type
General (Overview of some aspect of the database.)
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,'((?\1','g'),
'(LEFT JOIN|RIGHT JOIN|CROSS JOIN|FULL JOIN)','\1','g') AS def,
table_type
FROM user_defined_derived_tables
ORDER BY table_schema, table_name;
Collections
This query belongs to the following collections:
Name
Description
Find problems by overview
Queries 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
This query is classified under the following categories:
Name
Description
Derived tables
Queries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.