Skip to content

Commit 52e0892

Browse files
authored
Add check to find usage of varchar(32/36) instead of uuid for PK (#87)
* Add check to find usage of varchar(32/36) instead of uuid for PK * Fix linter
1 parent 23937e6 commit 52e0892

File tree

2 files changed

+45
-0
lines changed

2 files changed

+45
-0
lines changed

README.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -50,6 +50,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg
5050
26. Tables with zero or one column ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/tables_with_zero_or_one_column.sql)).
5151
27. Objects whose names do not follow naming convention ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/objects_not_following_naming_convention.sql)).
5252
28. Columns whose names do not follow naming convention ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/columns_not_following_naming_convention.sql)).
53+
29. Primary keys with varchar columns instead of uuids ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/primary_keys_with_varchar.sql)).
5354

5455
## Local development
5556

sql/primary_keys_with_varchar.sql

Lines changed: 44 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,44 @@
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 with columns of varchar(32/36/38) type.
9+
-- Usually this columns should use built-in uuid type.
10+
--
11+
-- See https://www.postgresql.org/docs/17/datatype-uuid.html
12+
-- b9b1f6f5-7f90-4b68-a389-f0ad8bb5784b - with dashes - 36 characters
13+
-- b9b1f6f57f904b68a389f0ad8bb5784b - without dashes - 32 characters
14+
-- {b9b1f6f5-7f90-4b68-a389-f0ad8bb5784b} - with curly braces - 38 characters
15+
select
16+
pc.oid::regclass::text as table_name,
17+
i.indexrelid::regclass as index_name,
18+
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by a.attnum) as columns
19+
from
20+
pg_catalog.pg_class pc
21+
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
22+
inner join pg_catalog.pg_index i on i.indrelid = pc.oid
23+
inner join pg_catalog.pg_attribute a on a.attrelid = pc.oid and a.attnum = any(i.indkey)
24+
where
25+
not a.attisdropped and
26+
a.attnum > 0 and
27+
not pc.relispartition and
28+
pc.relkind in ('r', 'p') and /* regular and partitioned tables */
29+
i.indisprimary and
30+
exists (
31+
select 1
32+
from
33+
pg_catalog.pg_attribute a2
34+
where
35+
a2.attrelid = pc.oid and
36+
a2.attnum = any(i.indkey) and
37+
not a2.attisdropped and
38+
a2.attnum > 0 and
39+
a2.atttypid = any('{varchar,bpchar}'::regtype[]) and
40+
(a2.atttypmod - 4) in (32, 36, 38)
41+
) and
42+
nsp.nspname = :schema_name_param::text
43+
group by pc.oid, i.indexrelid
44+
order by table_name, index_name;

0 commit comments

Comments
 (0)