Goal Find user-defined non-trigger SQL and PL/pgSQL routines that name starts with "set" (but not with "setting") but do not contain a UPDATE statement.
Notes The query does not consider the routines that are a part of an extension. 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.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion Rename the routine or make it update a row.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
SELECT 
routine_schema, 
routine_name, 
pg_get_function_identity_arguments(translate(substring(routines.specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters,
data_type AS return_type, 
is_deterministic, 
routine_type,
security_type,
external_language,
regexp_replace(pg_get_functiondef(translate(substring(routines.specific_name,'_[0-9]+$'),'_','')::int::oid),'[\r\n]','
','g') AS routine_src FROM information_schema.routines WHERE routine_schema NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) AND external_language IN ('PLPGSQL','SQL') AND routine_name NOT IN ('f_assume_you_must_use_files', 'f_check_format_comma_separated_list', 'f_check_password', 'f_default_value_with_no_match') AND NOT EXISTS (SELECT 1 FROM pg_catalog.pg_depend d inner join pg_catalog.pg_proc pc ON d.objid=pc.oid WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND pc.proname || '_' || pc.oid = routines.specific_name) AND (data_type<>'trigger' OR data_type IS NULL) AND routine_name~*'^set' AND routine_name!~*'^setting' AND pg_get_functiondef(translate(substring(routines.specific_name,'_[0-9]+$'),'_','')::int::oid)!~*'[[:space:]]*UPDATE[[:space:]]' ORDER BY routine_schema, routine_name, parameters;
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
NamingQueries of this category provide information about the style of naming.
User-defined routinesQueries of this category provide information about the user-defined routines