Skip to content

Commit a367123

Browse files
authored
Query to find primary keys with serial types (#46)
* Query to find primary keys with serial types * Fix formatting * Fix formatting * Update README.md
1 parent 4499765 commit a367123

File tree

2 files changed

+33
-0
lines changed

2 files changed

+33
-0
lines changed

README.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -41,6 +41,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg
4141
17. Tables with [not valid constraints](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/check_not_valid_constraints.sql)).
4242
18. B-tree indexes [on array columns](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/btree_indexes_on_array_columns.sql)).
4343
19. [Sequence overflow](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/sequence_overflow.sql)).
44+
20. Primary keys with [serial types](https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/primary_keys_with_serial_types.sql))
4445

4546
## Local development
4647

Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,32 @@
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 primary keys columns with serial type (smallserial/serial/bigserial)
9+
-- Instead of old smallserial/serial/bigserial new "generated as identity" syntax should be used
10+
-- for defining primary keys
11+
-- Based on https://dba.stackexchange.com/questions/90555/postgresql-select-primary-key-as-serial-or-bigserial/
12+
-- See also https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial
13+
-- and https://stackoverflow.com/questions/55300370/postgresql-serial-vs-identity
14+
select
15+
col.attrelid::regclass as table_name,
16+
col.attname as column_name,
17+
col.attnotnull as column_not_null,
18+
case col.atttypid
19+
when 'int'::regtype then 'serial'
20+
when 'int8'::regtype then 'bigserial'
21+
when 'int2'::regtype then 'smallserial' end as column_type,
22+
pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name
23+
from pg_catalog.pg_class t
24+
join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
25+
join pg_catalog.pg_attribute col on col.attrelid = t.oid
26+
join pg_catalog.pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
27+
join pg_catalog.pg_constraint c on c.conrelid = col.attrelid and col.attnum = any(c.conkey)
28+
where col.atttypid = any('{int,int8,int2}'::regtype[])
29+
and not col.attisdropped
30+
and c.contype = 'p' -- primary keys
31+
and pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)::regclass || '''::regclass)'
32+
and nsp.nspname = :schema_name_param::text;

0 commit comments

Comments
 (0)