The list of all the queries

A non-parameterized table function instead of a view

Query goal: Find table functions that do not have any parameters. Prefer simpler and more portable solutions.
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.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: High (Few or no false-positive results)
Query license: MIT License
Fixing suggestion: Create a view instead of the non-parameterized table function.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

SELECT 
  pg_namespace.nspname AS func_schema, 
  pg_proc.proname AS func_name, 
  regexp_replace(pg_get_functiondef(pg_proc.oid),'[\r\n]','<br>','g')  AS func_src,
  pg_type.typname AS return_type
FROM 
  pg_catalog.pg_proc, 
  pg_catalog.pg_namespace,
  pg_catalog.pg_type
WHERE   pg_proc.pronamespace = pg_namespace.oid 
AND pg_type.oid=pg_proc.prorettype
AND pg_proc.prokind='f'
AND  pg_type.typtype='c' 
AND pg_proc.pronargs=0
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 func_schema, func_name;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
SELECT format('DROP FUNCTION %1$I.%2$I;', pg_namespace.nspname, pg_proc.proname) AS statements
FROM 
  pg_catalog.pg_proc, 
  pg_catalog.pg_namespace,
  pg_catalog.pg_type
WHERE   pg_proc.pronamespace = pg_namespace.oid AND pg_type.oid=pg_proc.prorettype
AND pg_proc.prokind='f'
AND  pg_type.typtype='c' 
AND pg_proc.pronargs=0
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.

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
Derived tablesQueries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
User-defined routinesQueries of this category provide information about the user-defined routines

The list of all the queries