The list of all the queries

Perhaps searching based on a name instead of a code

Query goal: Find derived tables with a search condition that is possible based on a name instead of a code.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Low (Many false-positive results)
Query license: MIT License
Fixing suggestion: Typically names change more frequently than codes and thus the search conditions should refer to codes instead of names, if possible in order to reduce the need to rewrite views in case of data changes.
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
WHERE view_definition~*'(?<=WHERE.*)''[[:alpha:]]{6,}'''
ORDER BY table_schema, table_name;

Categories where the query belongs to

Category nameCategory description
Comfortability of data managementQueries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient.
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