Skip to content

Commit 1ad709f

Browse files
authored
Check to prevent unnecessary where-clauses in index creating queries on not null columns (#90)
* Standard name for pg_index alias * Add a check to prevent unnecessary where-clauses in index creating queries on not null columns
1 parent e2d7c33 commit 1ad709f

10 files changed

+95
-51
lines changed

CONTRIBUTING.md

Lines changed: 10 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -15,11 +15,16 @@ Each database structure check starts with an SQL query to the pg_catalog.
1515
```sql
1616
select
1717
psui.relid::regclass::text as table_name,
18-
psui.indexrelid::regclass::text as index_name,
18+
psui.indexrelid::regclass::text as index_name
1919
```
2020
4. All names should be enclosed in double quotes, if required.
21-
5. All query results must be ordered in some way.
22-
6. All queries must have a brief description.
21+
5. The columns for the index or foreign key must be returned in the order they are used in the index or foreign key:
22+
```sql
23+
select
24+
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by u.ordinality) as columns
25+
```
26+
6. All query results must be ordered in some way.
27+
7. All queries must have a brief description.
2328
Links to documentation or articles with detailed descriptions are welcome.
24-
7. Name of the sql-file with query must correspond to diagnostic name in [Java project](https://github.com/mfvanek/pg-index-health).
25-
8. Do not forget to update `README.md`.
29+
8. Name of the sql-file with query must correspond to diagnostic name in [Java project](https://github.com/mfvanek/pg-index-health).
30+
9. Do not forget to update `README.md`.

README.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -52,6 +52,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg
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)).
5353
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)).
5454
30. Columns with [varchar(n)](https://www.postgresql.org/docs/current/datatype-character.html) type ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/columns_with_fixed_length_varchar.sql)).
55+
31. Indexes with unnecessary where-clause on not null column ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/indexes_with_unnecessary_where_clause.sql)).
5556

5657
## Local development
5758

sql/btree_indexes_on_array_columns.sql

Lines changed: 6 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -11,16 +11,16 @@
1111
-- Based on query from https://habr.com/ru/articles/800121/
1212
-- See also https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
1313
select
14-
i.indrelid::regclass::text as table_name,
15-
i.indexrelid::regclass::text as index_name,
14+
pi.indrelid::regclass::text as table_name,
15+
pi.indexrelid::regclass::text as index_name,
1616
col.attnotnull as column_not_null,
1717
quote_ident(col.attname) as column_name,
18-
pg_relation_size(i.indexrelid) as index_size
19-
from pg_catalog.pg_index i
20-
inner join pg_catalog.pg_class ic on ic.oid = i.indexrelid
18+
pg_relation_size(pi.indexrelid) as index_size
19+
from pg_catalog.pg_index pi
20+
inner join pg_catalog.pg_class ic on ic.oid = pi.indexrelid
2121
inner join pg_catalog.pg_namespace nsp on nsp.oid = ic.relnamespace
2222
inner join pg_catalog.pg_am am on am.oid = ic.relam and am.amname = 'btree'
23-
inner join pg_catalog.pg_attribute col on col.attrelid = i.indrelid and col.attnum = any((string_to_array(i.indkey::text, ' ')::int2[])[:i.indnkeyatts])
23+
inner join pg_catalog.pg_attribute col on col.attrelid = pi.indrelid and col.attnum = any((string_to_array(pi.indkey::text, ' ')::int2[])[:pi.indnkeyatts])
2424
inner join pg_catalog.pg_type typ on typ.oid = col.atttypid
2525
where
2626
nsp.nspname = :schema_name_param::text and

sql/columns_with_serial_types.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -30,10 +30,10 @@ with
3030
pg_catalog.pg_class t
3131
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
3232
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
33-
inner join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
33+
inner join pg_catalog.pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
3434
left join lateral (
3535
select sum(case when c.contype = 'p' then +1 else -1 end) as res
36-
from pg_constraint c
36+
from pg_catalog.pg_constraint c
3737
where
3838
c.conrelid = col.attrelid and
3939
c.conkey[1] = col.attnum and

sql/duplicated_indexes.sql

Lines changed: 8 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -11,17 +11,17 @@ select
1111
string_agg('idx=' || idx::text || ', size=' || pg_relation_size(idx), '; ') as duplicated_indexes
1212
from (
1313
select
14-
x.indexrelid::regclass as idx,
15-
x.indrelid::regclass::text as table_name, /* cast to text for sorting purposes */
14+
pi.indexrelid::regclass as idx,
15+
pi.indrelid::regclass::text as table_name, /* cast to text for sorting purposes */
1616
(
17-
x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' ||
18-
x.indcollation::text || ' ' ||
19-
coalesce(pg_get_expr(x.indexprs, x.indrelid), '') || ' ' ||
20-
coalesce(pg_get_expr(x.indpred, x.indrelid), '')
17+
pi.indrelid::text || ' ' || pi.indclass::text || ' ' || pi.indkey::text || ' ' ||
18+
pi.indcollation::text || ' ' ||
19+
coalesce(pg_get_expr(pi.indexprs, pi.indrelid), '') || ' ' ||
20+
coalesce(pg_get_expr(pi.indpred, pi.indrelid), '')
2121
) as grouping_key
2222
from
23-
pg_catalog.pg_index x
24-
inner join pg_catalog.pg_class pc on pc.oid = x.indexrelid
23+
pg_catalog.pg_index pi
24+
inner join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
2525
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
2626
where
2727
nsp.nspname = :schema_name_param::text and

sql/indexes_with_null_values.sql

Lines changed: 10 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -7,21 +7,21 @@
77

88
-- Finds indexes that can contain null values.
99
select
10-
i.indrelid::regclass::text as table_name,
11-
i.indexrelid::regclass::text as index_name,
10+
pi.indrelid::regclass::text as table_name,
11+
pi.indexrelid::regclass::text as index_name,
1212
string_agg(quote_ident(a.attname), ', ') as nullable_fields, /* in fact, there will always be only one column */
13-
pg_relation_size(i.indexrelid) as index_size
13+
pg_relation_size(pi.indexrelid) as index_size
1414
from
15-
pg_catalog.pg_index i
16-
inner join pg_catalog.pg_class ic on ic.oid = i.indexrelid
15+
pg_catalog.pg_index pi
16+
inner join pg_catalog.pg_class ic on ic.oid = pi.indexrelid
1717
inner join pg_catalog.pg_namespace nsp on nsp.oid = ic.relnamespace
18-
inner join pg_catalog.pg_attribute a on a.attrelid = i.indrelid and a.attnum = any(i.indkey)
18+
inner join pg_catalog.pg_attribute a on a.attrelid = pi.indrelid and a.attnum = any(pi.indkey)
1919
where
20-
not i.indisunique and
20+
not pi.indisunique and
2121
not a.attnotnull and
2222
not ic.relispartition and
2323
nsp.nspname = :schema_name_param::text and
24-
array_position(i.indkey, a.attnum) = 0 and /* only for first segment */
25-
(i.indpred is null or (position(lower(a.attname) in lower(pg_get_expr(i.indpred, i.indrelid))) = 0))
26-
group by i.indrelid, i.indexrelid, i.indpred
24+
array_position(pi.indkey, a.attnum) = 0 and /* only for first segment */
25+
(pi.indpred is null or (position(lower(a.attname) in lower(pg_get_expr(pi.indpred, pi.indrelid))) = 0))
26+
group by pi.indrelid, pi.indexrelid, pi.indpred
2727
order by table_name, index_name;
Lines changed: 36 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,36 @@
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 indexes that have a redundant predicate with the where-clause 'column is not null' for the not null column.
9+
-- AL01
10+
select
11+
pc.oid::regclass::text as table_name,
12+
pi.indexrelid::regclass::text as index_name,
13+
pg_relation_size(pi.indexrelid) as index_size,
14+
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by u.ordinality) as columns
15+
from
16+
pg_catalog.pg_index pi
17+
inner join pg_catalog.pg_class pc on pc.oid = pi.indrelid
18+
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
19+
inner join unnest(pi.indkey) with ordinality u(attnum, ordinality) on true
20+
inner join pg_catalog.pg_attribute a on a.attrelid = pc.oid and a.attnum = u.attnum
21+
where
22+
pc.relkind in ('r', 'p') and /* regular and partitioned tables */
23+
not pc.relispartition and
24+
pi.indpred is not null and
25+
exists (
26+
select 1
27+
from
28+
unnest(pi.indkey) k(attnum)
29+
inner join pg_catalog.pg_attribute att on att.attrelid = pc.oid and att.attnum = k.attnum
30+
where
31+
att.attnotnull = true and
32+
pg_get_indexdef(pi.indexrelid) ilike '%where%' || quote_ident(att.attname) || ' is not null%'
33+
) and
34+
nsp.nspname = :schema_name_param::text
35+
group by pc.oid, pi.indexrelid
36+
order by table_name, index_name;

sql/invalid_indexes.sql

Lines changed: 6 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -8,12 +8,13 @@
88
-- Finds invalid indexes that might have appeared as a result of
99
-- unsuccessful execution of the 'create index concurrently' command.
1010
select
11-
x.indrelid::regclass::text as table_name,
12-
x.indexrelid::regclass::text as index_name
11+
pi.indrelid::regclass::text as table_name,
12+
pi.indexrelid::regclass::text as index_name,
13+
pg_relation_size(pi.indexrelid) as index_size
1314
from
14-
pg_catalog.pg_index x
15-
inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = x.indexrelid
15+
pg_catalog.pg_index pi
16+
inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = pi.indexrelid
1617
where
1718
psai.schemaname = :schema_name_param::text and
18-
x.indisvalid = false
19+
pi.indisvalid = false
1920
order by table_name, index_name;

sql/primary_keys_with_varchar.sql

Lines changed: 9 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -14,32 +14,33 @@
1414
-- {b9b1f6f5-7f90-4b68-a389-f0ad8bb5784b} - with curly braces - 38 characters
1515
select
1616
pc.oid::regclass::text as table_name,
17-
i.indexrelid::regclass as index_name,
18-
pg_relation_size(i.indexrelid) as index_size,
19-
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by a.attnum) as columns
17+
pi.indexrelid::regclass as index_name,
18+
pg_relation_size(pi.indexrelid) as index_size,
19+
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by u.ordinality) as columns
2020
from
2121
pg_catalog.pg_class pc
2222
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
23-
inner join pg_catalog.pg_index i on i.indrelid = pc.oid
24-
inner join pg_catalog.pg_attribute a on a.attrelid = pc.oid and a.attnum = any(i.indkey)
23+
inner join pg_catalog.pg_index pi on pi.indrelid = pc.oid
24+
inner join unnest(pi.indkey) with ordinality u(attnum, ordinality) on true
25+
inner join pg_catalog.pg_attribute a on a.attrelid = pc.oid and a.attnum = u.attnum
2526
where
2627
not a.attisdropped and
2728
a.attnum > 0 and
2829
not pc.relispartition and
2930
pc.relkind in ('r', 'p') and /* regular and partitioned tables */
30-
i.indisprimary and
31+
pi.indisprimary and
3132
exists (
3233
select 1
3334
from
3435
pg_catalog.pg_attribute a2
3536
where
3637
a2.attrelid = pc.oid and
37-
a2.attnum = any(i.indkey) and
38+
a2.attnum = any(pi.indkey) and
3839
not a2.attisdropped and
3940
a2.attnum > 0 and
4041
a2.atttypid = any('{varchar,bpchar}'::regtype[]) and
4142
(a2.atttypmod - 4) in (32, 36, 38)
4243
) and
4344
nsp.nspname = :schema_name_param::text
44-
group by pc.oid, i.indexrelid
45+
group by pc.oid, pi.indexrelid
4546
order by table_name, index_name;

sql/unused_indexes.sql

Lines changed: 7 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -20,26 +20,26 @@ with
2020
),
2121

2222
foreign_key_indexes as (
23-
select i.indexrelid
23+
select pi.indexrelid
2424
from
2525
pg_catalog.pg_constraint c
2626
inner join nsp on nsp.oid = c.connamespace
2727
inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true
28-
inner join pg_catalog.pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ i.indkey::int[])
28+
inner join pg_catalog.pg_index pi on pi.indrelid = c.conrelid and (c.conkey::int[] <@ pi.indkey::int[])
2929
where c.contype = 'f'
3030
)
3131

3232
select
3333
psui.relid::regclass::text as table_name,
3434
psui.indexrelid::regclass::text as index_name,
3535
psui.idx_scan as index_scans,
36-
pg_relation_size(i.indexrelid) as index_size
36+
pg_relation_size(pi.indexrelid) as index_size
3737
from
3838
pg_catalog.pg_stat_user_indexes psui
39-
inner join pg_catalog.pg_index i on i.indexrelid = psui.indexrelid
39+
inner join pg_catalog.pg_index pi on pi.indexrelid = psui.indexrelid
4040
where
4141
psui.schemaname in (select nspname from nsp) and
42-
not i.indisunique and
43-
i.indexrelid not in (select * from foreign_key_indexes) and /* retain indexes on foreign keys */
42+
not pi.indisunique and
43+
pi.indexrelid not in (select * from foreign_key_indexes) and /* retain indexes on foreign keys */
4444
psui.idx_scan < 50::integer
45-
order by table_name, pg_relation_size(i.indexrelid) desc;
45+
order by table_name, pg_relation_size(pi.indexrelid) desc;

0 commit comments

Comments
 (0)