Query goal: | Find deterministic (immutable) functions that do not return a value. This goes against the idea of deterministic functions. |
Notes about the query: | Refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. 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. 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. The query does not consider the routines that are a part of an extension. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | Medium (Medium number of false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Change the function so that it returns a value when it is invoked. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
SELECT pg_namespace.nspname AS routine_schema, pg_proc.proname AS routine_name, pg_get_function_identity_arguments(pg_proc.oid) AS parameters, regexp_replace(pg_get_functiondef(pg_proc.oid),'[\r\n]','<br>','g') AS routine_src FROM pg_catalog.pg_proc INNER JOIN pg_catalog.pg_namespace ON pg_proc.pronamespace = pg_namespace.oid INNER JOIN pg_catalog.pg_type ON pg_proc.prorettype = pg_type.oid WHERE pg_proc.provolatile='i' AND pg_proc.prokind='f' AND pg_type.typname='void' 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) AND NOT EXISTS (SELECT 1 FROM pg_catalog.pg_depend d WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND d.objid=pg_proc.oid) ORDER BY routine_schema, routine_name, parameters; |
SQL query | Description |
---|---|
SELECT format('DROP FUNCTION %1$I.%2$I(%3$s);', pg_namespace.nspname, pg_proc.proname, pg_get_function_identity_arguments(pg_proc.oid)) AS statements FROM pg_catalog.pg_proc INNER JOIN pg_catalog.pg_namespace ON pg_proc.pronamespace = pg_namespace.oid INNER JOIN pg_catalog.pg_type ON pg_proc.prorettype = pg_type.oid WHERE pg_proc.provolatile='i' AND pg_proc.prokind='f' AND pg_type.typname='void' 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 pg_namespace.nspname, pg_proc.proname; | Drop the function. |
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 |
---|---|
Does not work in some earlier PostgreSQL version | Queries of this category provide information that was not available in some earlier PostgreSQL version |
User-defined routines | Queries of this category provide information about the user-defined routines |