Query goal: | Avoid using NOT IN or <>ALL with a non-correlated subquery in PostgreSQL because the query performance will be very poor, especially in case of large data sizes. |
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. The query excludes subqueries with "NOT IN (SELECT DISTINCT" because in this case the DBMS selects an execution plan that has better performance. |
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 |
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 ~*'^.*((?<=not.*)[[:space:]]in|not[[:space:]]*in|<>[[:space:]]*all)[[:space:]]*[(](?=[^)]+select)(?![^)]+distinct)' ORDER BY table_schema, table_name; |
Collection name | Collection description |
---|---|
Find problems automatically | Queries, 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 . |
Category name | Category description |
---|---|
Derived tables | Queries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer. |
Performance | Queries of this category provide information about indexes in a database. |