Goal Working with sets of rows rather than processing each row separately is more effective.
Notes 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.
Type General (Overview of some aspect of the database.)
License MIT License
Fixing Suggestion Prefer working with sets of rows to working with rows one-by-one. Many tasks in a SQL database can be solved by using SQL's declarative data manipulation language statements, instead of writing procedural code.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH pl_pgsql_routine AS (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(pg_get_functiondef(pg_proc.oid),'[\r\n]','
','g') AS routine_src FROM pg_catalog.pg_proc, pg_catalog.pg_namespace, pg_catalog.pg_language WHERE pg_proc.pronamespace = pg_namespace.oid AND pg_proc.prokind<>'a' AND pg_proc.prolang = pg_language.oid AND pg_language.lanname='plpgsql' 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)) SELECT routine_schema, routine_name, parameters, routine_type, routine_src FROM pl_pgsql_routine WHERE routine_src ~*'([[:space:]]+refcursor;|[[:space:]]+cursor[[:space:]]+)' ORDER BY routine_schema, routine_name, parameters;
Collections

This query belongs to the following collections:

NameDescription
Find problems by overviewQueries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not .
Categories

This query is classified under the following categories:

NameDescription
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
PerformanceQueries of this category provide information about indexes in a database.
User-defined routinesQueries of this category provide information about the user-defined routines