The list of all the queries

Case sensitive and case insensitive uniqueness of the same simple key

Query goal: Find sets of columns that have both case sensitive and case insesitive unique constraints enforced based on these columns. In case of textual columns uniqueness could be checked either in case sensitive or case insensitive way. It is a contradiction to check the uniqueneness in both ways in case of the same key.
Notes about the query: The query considers both unique indexes and exclusion constraints. The query only considers constraints/indexes that involve one column.
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 either the constraint that enforces case sensitive uniqueness or the unique index that enforces case insensitive uniqueness.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

with idx AS (SELECT 
n.nspname AS index_schema,
c.relname AS index_name,
c2.relname AS table_name,
i.indrelid AS index_table_oid,
unnest(indkey) AS index_col
FROM pg_catalog.pg_index AS i INNER JOIN pg_catalog.pg_class AS c ON i.indexrelid=c.oid
INNER JOIN pg_catalog.pg_class AS c2 ON i.indrelid=c2.oid
INNER JOIN pg_catalog.pg_namespace n ON c.relnamespace=n.oid
WHERE indisunique=true AND indnatts=1 AND nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
idx_with_names as (select index_name, index_schema, table_name, a_idx.attname as column_name
from idx k inner join pg_attribute a_idx on k.index_col = a_idx.attnum and k.index_table_oid = a_idx.attrelid and a_idx.attisdropped = false
inner join pg_type t on a_idx.atttypid=t.oid 
left join pg_type td on t.typbasetype=td.oid
where coalesce(td.typname, t.typname)='text' or coalesce(td.typname, t.typname) like '%char%'),
unique_function_based_indexes AS (SELECT schemaname, tablename, indexdef, indexname
FROM (SELECT schemaname, tablename, indexdef, indexname
FROM pg_catalog.pg_indexes
WHERE indexdef~*'unique[[:space:]]+index.+(upper|lower)[(]'
union select 
(select nspname from pg_namespace where oid=c.relnamespace) as excl_schema,
c.relname as excl_table, 
pg_get_indexdef(o.conindid) as index_def,
c2.relname as index_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class c2 on  o.conindid=c2.oid
where o.contype in ('x')
and pg_get_indexdef(o.conindid) ~*'(upper|lower)') AS foo
WHERE schemaname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL))
SELECT index_schema, table_name, column_name, index_name as case_sensitive_index_name, p.indexname as case_insensitive_index_name, p.indexdef as case_insensitive_index_definition 
FROM idx_with_names i, unique_function_based_indexes p
WHERE i.index_schema=p.schemaname 
AND i.table_name=p.tablename 
AND p.indexdef~*('[(].*'||i.column_name || '[)]')
ORDER BY index_schema, table_name, column_name;

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

SQL queryDescription
with idx AS (SELECT 
n.nspname AS index_schema,
c.relname AS index_name,
c2.relname AS table_name,
i.indrelid AS index_table_oid,
unnest(indkey) AS index_col
FROM pg_catalog.pg_index AS i INNER JOIN pg_catalog.pg_class AS c ON i.indexrelid=c.oid
INNER JOIN pg_catalog.pg_class AS c2 ON i.indrelid=c2.oid
INNER JOIN pg_catalog.pg_namespace n ON c.relnamespace=n.oid
WHERE indisunique=true AND indnatts=1 AND nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
idx_with_names as (select index_name, index_schema, table_name, a_idx.attname as column_name
from idx k inner join pg_attribute a_idx on k.index_col = a_idx.attnum and k.index_table_oid = a_idx.attrelid and a_idx.attisdropped = false
inner join pg_type t on a_idx.atttypid=t.oid 
left join pg_type td on t.typbasetype=td.oid
where coalesce(td.typname, t.typname)='text' or coalesce(td.typname, t.typname) like '%char%')
SELECT format('DROP INDEX %1$I.%2$I;', index_schema, p.indexname) AS statements
FROM idx_with_names i, pg_catalog.pg_indexes p
WHERE i.index_schema=p.schemaname AND i.table_name=p.tablename AND (p.indexdef LIKE '%(upper(%' || i.column_name || ')%' OR
p.indexdef LIKE '%(lower(%' || i.column_name || ')%')
ORDER BY index_schema, table_name, column_name;
Drop the case sensitive index.

Collections where the query belongs to

Collection nameCollection description
Find problems about integrity constraintsA selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview
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
Case sensitivity vs. case insensitivityQueries of this category provide information about case sensitivity/insensitivity of identifiers or user data.
PerformanceQueries of this category provide information about indexes in a database.
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.
Validity and completenessQueries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness).

The list of all the queries