The list of all the queries

Case insensitive search

Query goal: Refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. Find user-defined routines and derived tables (views/materialized views) that have a subquery with case insensitive search (by using the upper or lower function or ILIKE predicate or (?i) modifier of a regular expression pattern).
Notes about the query: Refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. The query uses system information function pg_get_viewdef to get the view subquery pretty printed, i.e., without excessive brackets. The query does not consider the routines that are a part of an extension. In the returned body of subquery of view/materialized view/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: General (Overview of some aspect of the database.)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH derived_tables AS (SELECT n.nspname AS schema_name, 
c.relname AS object_name,
CASE WHEN c.relkind='v' THEN 'VIEW'
WHEN c.relkind='m' THEN 'MATERIALIZED VIEW'
END AS object_type,
pg_get_viewdef(c.oid, true) AS object_definition,
regexp_replace(pg_get_viewdef(c.oid, true),'[\r\n]','<br>','g') AS object_def
FROM pg_namespace AS n INNER JOIN pg_authid AS a ON n.nspowner=a.oid
INNER JOIN pg_class AS c ON n.oid=c.relnamespace
WHERE (n.nspname='public' OR a.rolname<>'postgres')
AND relkind IN ('v','m')),
routines AS (SELECT 
  pg_namespace.nspname AS schema_name, 
  pg_proc.proname || '(' || pg_get_function_identity_arguments(pg_proc.oid) || ')' AS object_name,
  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 object_type,
   pg_get_functiondef(pg_proc.oid) AS object_definition,
  regexp_replace( regexp_replace( pg_get_functiondef(pg_proc.oid),'<','&lt','g'),'[\r\n]','<br>','g')  AS object_def
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 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)),
checked_elements AS (SELECT schema_name, object_name, object_type, object_definition, object_def
FROM derived_tables
UNION SELECT schema_name, object_name, object_type, object_definition, object_def
FROM routines)
SELECT schema_name, object_name, object_type, object_def
FROM checked_elements
WHERE object_definition ~*'(where|having).+([[:space:]]upper[[:space:]]*[(]|[[:space:]]lower[[:space:]]*[(]|~[*][[:space:]]*|[[:space:]]ilike[[:space:]]*|[(][?]i[)])'
ORDER BY schema_name, object_type, object_name;

Collections where the query belongs to

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

Category nameCategory description
Case sensitivity vs. case insensitivityQueries of this category provide information about case sensitivity/insensitivity of identifiers or user data.
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
System-defined functionsQueries of this category provide information about the use of system-defined functions.
User-defined routinesQueries of this category provide information about the user-defined routines

Reference materials for further reading

Reference
https://stackoverflow.com/questions/7005302/postgresql-how-to-make-case-insensitive-query

The list of all the queries