|
| 1 | +/* |
| 2 | + * Copyright (c) 2019-2024. 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 objects whose names have a length of max_identifier_length (usually it is 63). |
| 9 | +-- The problem is that Postgres silently truncates such long names. |
| 10 | +-- For example, if you have a migration where you are trying to create two objects with very long names |
| 11 | +-- that start the same way (such as an index or constraint) and you use the "if not exists" statement, |
| 12 | +-- you might end up with only one object in the database instead of two. |
| 13 | +-- |
| 14 | +-- If there is an object with a name of maximum length in the database, then an overflow may have occurred. |
| 15 | +-- It is advisable to avoid such situations and use shorter names. |
| 16 | +-- |
| 17 | +-- See https://www.postgresql.org/docs/current/runtime-config-preset.html#GUC-MAX-IDENTIFIER-LENGTH |
| 18 | +-- See https://www.postgresql.org/docs/current/catalog-pg-class.html |
| 19 | +with |
| 20 | + t as ( |
| 21 | + select current_setting('max_identifier_length')::int as max_identifier_length |
| 22 | + ), |
| 23 | + |
| 24 | + long_names as ( |
| 25 | + select |
| 26 | + pc.oid::regclass::text as object_name, |
| 27 | + case pc.relkind |
| 28 | + when 'r' then 'table' |
| 29 | + when 'i' then 'index' |
| 30 | + when 'S' then 'sequence' |
| 31 | + when 'v' then 'view' |
| 32 | + when 'm' then 'materialized view' |
| 33 | + end as object_type |
| 34 | + from |
| 35 | + pg_catalog.pg_class pc |
| 36 | + inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace |
| 37 | + inner join t on t.max_identifier_length = length(pc.relname) |
| 38 | + where |
| 39 | + pc.relkind in ('r', 'i', 'S', 'v', 'm') and |
| 40 | + nsp.nspname = :schema_name_param::text |
| 41 | + |
| 42 | + union all |
| 43 | + |
| 44 | + select |
| 45 | + case when nsp.nspname = 'public' then p.proname else nsp.nspname || '.' || p.proname end as object_name, |
| 46 | + 'function' as object_type |
| 47 | + from |
| 48 | + pg_catalog.pg_proc p |
| 49 | + inner join pg_catalog.pg_namespace nsp on nsp.oid = p.pronamespace |
| 50 | + inner join t on t.max_identifier_length = length(p.proname) |
| 51 | + where |
| 52 | + nsp.nspname = :schema_name_param::text |
| 53 | + |
| 54 | + union all |
| 55 | + |
| 56 | + select |
| 57 | + case when nsp.nspname = 'public' then c.conname else nsp.nspname || '.' || c.conname end as object_name, |
| 58 | + 'constraint' as object_type |
| 59 | + from |
| 60 | + pg_catalog.pg_constraint c |
| 61 | + inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace |
| 62 | + inner join t on t.max_identifier_length = length(c.conname) |
| 63 | + where |
| 64 | + nsp.nspname = :schema_name_param::text |
| 65 | + ) |
| 66 | + |
| 67 | +select * |
| 68 | +from long_names |
| 69 | +order by object_type, object_name; |
0 commit comments