|
| 1 | +/* |
| 2 | + * Copyright (c) 2019-2025. Ivan Vakhrushev and others. |
| 3 | + * https://github.com/mfvanek/pg-index-health-sql |
| 4 | + * |
| 5 | + * Licensed under the Apache License 2.0 |
| 6 | + */ |
| 7 | + |
| 8 | +-- Finds primary keys that are most likely natural keys. |
| 9 | +-- It is better to use surrogate keys instead of natural ones. |
| 10 | +-- See https://www.youtube.com/watch?v=s6m8Aby2at8 |
| 11 | +-- See also https://www.databasestar.com/database-keys/ |
| 12 | +with |
| 13 | + nsp as ( |
| 14 | + select |
| 15 | + nsp.oid, |
| 16 | + nsp.nspname |
| 17 | + from pg_catalog.pg_namespace nsp |
| 18 | + where |
| 19 | + nsp.nspname = :schema_name_param::text |
| 20 | + ) |
| 21 | + |
| 22 | +select |
| 23 | + t.oid::regclass::text as table_name, |
| 24 | + c.conindid::regclass::text as index_name, |
| 25 | + pg_relation_size(c.conindid) as index_size, |
| 26 | + array_agg(quote_ident(col.attname) || ',' || col.attnotnull::text order by u.attposition) as columns |
| 27 | +from |
| 28 | + pg_catalog.pg_constraint c |
| 29 | + inner join pg_catalog.pg_class t on t.oid = c.conrelid |
| 30 | + inner join nsp on nsp.oid = c.connamespace |
| 31 | + inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true |
| 32 | + inner join pg_catalog.pg_attribute col on col.attrelid = t.oid and col.attnum = u.attnum |
| 33 | +where |
| 34 | + c.contype = 'p' and /* primary key constraint */ |
| 35 | + c.conparentid = 0 and c.coninhcount = 0 and /* not a constraint in a partition */ |
| 36 | + t.relkind = 'r' /* only regular tables */ |
| 37 | +group by t.oid, c.conindid |
| 38 | +having bool_or( |
| 39 | + col.atttypid not in ( |
| 40 | + 'smallint'::regtype, |
| 41 | + 'integer'::regtype, |
| 42 | + 'bigint'::regtype, |
| 43 | + 'uuid'::regtype |
| 44 | + ) |
| 45 | +) |
| 46 | + |
| 47 | +union all |
| 48 | + |
| 49 | +select |
| 50 | + t.oid::regclass::text as table_name, |
| 51 | + c.conindid::regclass::text as index_name, |
| 52 | + pg_relation_size(c.conindid) as index_size, |
| 53 | + array_agg(quote_ident(col.attname) || ',' || col.attnotnull::text order by u.attposition) as columns |
| 54 | +from |
| 55 | + pg_catalog.pg_constraint c |
| 56 | + inner join pg_catalog.pg_class t on t.oid = c.conrelid |
| 57 | + inner join nsp on nsp.oid = c.connamespace |
| 58 | + inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true |
| 59 | + inner join pg_catalog.pg_attribute col on col.attrelid = t.oid and col.attnum = u.attnum |
| 60 | +where |
| 61 | + c.contype = 'p' and /* primary key constraint */ |
| 62 | + c.conparentid = 0 and c.coninhcount = 0 and /* not a constraint in a partition */ |
| 63 | + t.relkind = 'p' and /* only partitioned tables */ |
| 64 | + not t.relispartition |
| 65 | +group by t.oid, c.conindid |
| 66 | +having bool_or( |
| 67 | + /* for partitioned tables decided to allow a few more data types that usually are used in ranges */ |
| 68 | + col.atttypid not in ( |
| 69 | + 'smallint'::regtype, |
| 70 | + 'integer'::regtype, |
| 71 | + 'bigint'::regtype, |
| 72 | + 'uuid'::regtype, |
| 73 | + 'date'::regtype, |
| 74 | + 'timestamp'::regtype, |
| 75 | + 'timestamptz'::regtype, |
| 76 | + 'time'::regtype, |
| 77 | + 'timetz'::regtype |
| 78 | + ) |
| 79 | +) |
| 80 | +order by table_name, index_name; |
0 commit comments