Query goal: | Find routines that use SELECT … FOR UPDATE without selecting rows from a specific table. For instance: SELECT 'text' AS v FOR UPDATE; |
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: | Drop the routine and recreate it. |
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, 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( regexp_replace(pg_get_functiondef(pg_proc.oid),'<','<','g'),'[\r\n]','<br>','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_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 pg_get_functiondef(pg_proc.oid)~*'[[:space:]]select[[:space:]][^;]+for[[:space:]]+update[[:space:]]*[;]' AND pg_get_functiondef(pg_proc.oid)!~*'[[:space:]]select[[:space:]][^;]*[[:space:]]from[[:space:]][^;]*for[[:space:]]+update[[:space:]]*[;]' ORDER BY routine_schema, routine_name, parameters; |
SQL query | Description |
---|---|
WITH unnecessary_for_update AS (SELECT pg_namespace.nspname AS routine_schema, pg_proc.proname AS routine_name, pg_get_function_identity_arguments(pg_proc.oid) AS parameters 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_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 pg_get_functiondef(pg_proc.oid)~*'[[:space:]]select[[:space:]][^;]+for[[:space:]]+update[[:space:]]*[;]' AND pg_get_functiondef(pg_proc.oid)!~*'[[:space:]]select[[:space:]][^;]*[[:space:]]from[[:space:]][^;]*for[[:space:]]+update[[:space:]]*[;]') SELECT format('DROP ROUTINE %1$s.%2$s(%3$s);', routine_schema, routine_name, parameters) AS statements FROM unnecessary_for_update ORDER BY routine_schema, routine_name, parameters; | Drop the routine. |
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 |
---|---|
Concurrency control | Queries of this category provide information about concurrency control. |
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 |