The list of all the queries

Perhaps inconsistent use of temporal functions

Query goal: Find routines that use temporal functions CURRENT_TIMESTAMP, LOCALTIMESTAMP, or now() that is inconsistent with the default values of the columns that are used by the routine, e.g., function uses a column with the default value LOCALTIMESTAMP but the routine uses function CURRENT_TIMESTAMP or now().
Notes about the query: The query only considers routines that have SQL-standard function body. 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.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Low (Many false-positive results)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH routines AS (SELECT 
  pg_namespace.nspname AS specific_schema, 
  pg_proc.proname AS routine_name,   
  pg_proc.proname || '_' || pg_proc.oid AS specific_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]','<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_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)~*'(localtimestamp|current_timestamp|now[(][)])'
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)),
temp_columns AS (SELECT A.table_schema, A.table_name , A.column_name, A.data_type,A.column_default, D.domain_default
FROM information_schema.columns A
INNER JOIN information_schema.tables T USING (table_schema, table_name)
INNER JOIN information_schema.schemata S ON A.table_schema=S.schema_name
LEFT JOIN information_schema.domains D USING (domain_schema, domain_name)
WHERE A.data_type~*'(timestamp|date)'
AND T.table_type='BASE TABLE'
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
AND coalesce(A.column_default, D.domain_default)~*'(localtimestamp|current_timestamp|now[(][)])')
SELECT specific_schema AS routine_schema, routines.routine_name, parameters, routine_type, routine_src, table_schema, table_name, column_name, column_default, domain_default
FROM routines INNER JOIN INFORMATION_SCHEMA.routine_column_usage USING (specific_schema, specific_name)
INNER JOIN temp_columns USING (table_schema, table_name, column_name)
WHERE routine_src NOT ILIKE '%' || coalesce(column_default, domain_default) || '%'
ORDER BY routine_schema, routines.routine_name, parameters;

Collections where the query belongs to

Collection nameCollection description
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 where the query belongs to

Category nameCategory description
Default valueQueries of this catergory provide information about the use of default values.
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
InconsistenciesQueries of this catergory provide information about inconsistencies of solving the same problem in different places.
User-defined routinesQueries of this category provide information about the user-defined routines

The list of all the queries