Goal Avoid using NOT IN or <>ALL with a non-correlated subquery in PostgreSQL because the query performance will be very poor.
Notes Refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. There could be multiple routines with the same name but with different parameters in the same schema (overloading). Thus, for the unique identification of the routine it is necessary to present also its parameters in addition to the schema name and routine name. In the returned body of routine 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.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability High (Few or no false-positive results)
License MIT License
Fixing Suggestion Rewrite the query so that it uses NOT EXISTS predicate with correlated subquery.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
SELECT 
  pg_namespace.nspname AS routine_schema, 
  pg_proc.proname AS routine_name, 
  pg_get_function_identity_arguments(pg_proc.oid) AS parameters,
  CASE WHEN pg_proc.prokind='f' THEN 'FUNCTION'
  WHEN pg_proc.prokind='p' THEN 'PROCEDURE'
  WHEN pg_proc.prokind='w' THEN 'WINDOW FUNCTION' END AS routine_type,
 regexp_replace(pg_get_functiondef(pg_proc.oid),'[\r\n]','
','g') AS routine_src FROM pg_catalog.pg_proc, pg_catalog.pg_namespace WHERE pg_proc.pronamespace = pg_namespace.oid AND pg_proc.prokind<>'a' AND pg_proc.proname NOT IN ('f_assume_you_must_use_files', 'f_check_format_comma_separated_list', 'f_check_password', 'f_default_value_with_no_match') AND pg_get_functiondef(pg_proc.oid)~*'^.*((?<=not[^;]*)[[:space:]]in|not[[:space:]]*in|<>[[:space:]]*all)[[:space:]]*[(](?=[^)]+select)(?![^)]+distinct)' AND pg_namespace.nspname NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) ORDER BY routine_schema, routine_name;
Collections

This query belongs to the following collections:

NameDescription
Find problems automaticallyQueries, 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 .
Categories

This query is classified under the following categories:

NameDescription
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
PerformanceQueries of this category provide information about indexes in a database.
User-defined routinesQueries of this category provide information about the user-defined routines