Find non-function based indexes (both unique and non-unique) that have identical first column but the operator class that is used in case of the first column is different. Include unique indexes that support a constraint (primary key, unique, exclude), i.e., these indexes have been automatically created due to the constraint declaration.
Type
General (Overview of some aspect of the database.)
WITH indexes AS (SELECT
n.nspname AS sch,
c2.relname AS tbl,
c.relname AS indx,
array_agg(a.attname ORDER BY a.attnum) AS clm,
i.indisunique,
indclass[0] AS operator_class,
pg_get_indexdef(c.oid) AS index_def,
EXISTS (SELECT * FROM pg_catalog.pg_constraint AS o WHERE o.conindid=i.indexrelid) AS is_constraint
FROM
pg_catalog.pg_class AS c INNER JOIN pg_catalog.pg_index AS i ON i.indexrelid = c.oid
INNER JOIN pg_catalog.pg_class AS c2 ON i.indrelid = c2.oid
INNER JOIN pg_catalog.pg_namespace AS n ON c.relnamespace = n.oid
INNER JOIN pg_catalog.pg_authid AS u ON n.nspowner = u.oid
INNER JOIN pg_catalog.pg_attribute AS a ON a.attrelid = c.oid
WHERE c.relkind = 'i'
AND i.indexprs IS NULL
AND a.attnum>=1
AND a.attisdropped = FALSE
AND (n.nspname = 'public'
OR u.rolname <> 'postgres')
GROUP BY n.nspname, c2.relname, c.relname, i.indisunique, indclass[0], index_def, is_constraint),
index_with_type AS (SELECT sch, tbl, indx, clm, operator_class, index_def,
CASE WHEN is_constraint=TRUE THEN 'UNIQUE CONSTRAINT INDEX'
WHEN indisunique=TRUE AND is_constraint=FALSE THEN 'UNIQUE NON-CONSTRAINT INDEX'
ELSE 'NON-UNIQUE INDEX' END AS index_type
FROM indexes)
SELECT A.sch AS table_schema, A.tbl AS table_name, A.index_type AS idx1_index_type, A.indx AS idx1, A.index_def AS idx1_def,
B.index_def AS idx2_def, B.index_type AS idx2_index_type, B.indx AS idx2
FROM index_with_type AS A, index_with_type AS B
WHERE A.sch=B.sch AND A.tbl=B.tbl AND A.indx>B.indx AND A.clm[1]=B.clm[1] AND A.operator_class<>B.operator_class
ORDER BY A.sch, A.tbl, A.indx, B.indx;
Collections
This query belongs to the following collections:
Name
Description
Find problems by overview
Queries 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:
Name
Description
Performance
Queries of this category provide information about indexes in a database.