Skip to content

Check to prevent unnecessary where-clauses in index creating queries on not null columns #90

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 6 commits into from
Apr 19, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
15 changes: 10 additions & 5 deletions CONTRIBUTING.md
Original file line number Diff line number Diff line change
Expand Up @@ -15,11 +15,16 @@ Each database structure check starts with an SQL query to the pg_catalog.
```sql
select
psui.relid::regclass::text as table_name,
psui.indexrelid::regclass::text as index_name,
psui.indexrelid::regclass::text as index_name
```
4. All names should be enclosed in double quotes, if required.
5. All query results must be ordered in some way.
6. All queries must have a brief description.
5. The columns for the index or foreign key must be returned in the order they are used in the index or foreign key:
```sql
select
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by u.ordinality) as columns
```
6. All query results must be ordered in some way.
7. All queries must have a brief description.
Links to documentation or articles with detailed descriptions are welcome.
7. Name of the sql-file with query must correspond to diagnostic name in [Java project](https://github.com/mfvanek/pg-index-health).
8. Do not forget to update `README.md`.
8. Name of the sql-file with query must correspond to diagnostic name in [Java project](https://github.com/mfvanek/pg-index-health).
9. Do not forget to update `README.md`.
1 change: 1 addition & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -52,6 +52,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg
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)).
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)).
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)).
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)).

## Local development

Expand Down
12 changes: 6 additions & 6 deletions sql/btree_indexes_on_array_columns.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,16 +11,16 @@
-- Based on query from https://habr.com/ru/articles/800121/
-- See also https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
select
i.indrelid::regclass::text as table_name,
i.indexrelid::regclass::text as index_name,
pi.indrelid::regclass::text as table_name,
pi.indexrelid::regclass::text as index_name,
col.attnotnull as column_not_null,
quote_ident(col.attname) as column_name,
pg_relation_size(i.indexrelid) as index_size
from pg_catalog.pg_index i
inner join pg_catalog.pg_class ic on ic.oid = i.indexrelid
pg_relation_size(pi.indexrelid) as index_size
from pg_catalog.pg_index pi
inner join pg_catalog.pg_class ic on ic.oid = pi.indexrelid
inner join pg_catalog.pg_namespace nsp on nsp.oid = ic.relnamespace
inner join pg_catalog.pg_am am on am.oid = ic.relam and am.amname = 'btree'
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])
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])
inner join pg_catalog.pg_type typ on typ.oid = col.atttypid
where
nsp.nspname = :schema_name_param::text and
Expand Down
4 changes: 2 additions & 2 deletions sql/columns_with_serial_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,10 +30,10 @@ with
pg_catalog.pg_class t
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
inner join pg_catalog.pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
left join lateral (
select sum(case when c.contype = 'p' then +1 else -1 end) as res
from pg_constraint c
from pg_catalog.pg_constraint c
where
c.conrelid = col.attrelid and
c.conkey[1] = col.attnum and
Expand Down
16 changes: 8 additions & 8 deletions sql/duplicated_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,17 +11,17 @@ select
string_agg('idx=' || idx::text || ', size=' || pg_relation_size(idx), '; ') as duplicated_indexes
from (
select
x.indexrelid::regclass as idx,
x.indrelid::regclass::text as table_name, /* cast to text for sorting purposes */
pi.indexrelid::regclass as idx,
pi.indrelid::regclass::text as table_name, /* cast to text for sorting purposes */
(
x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' ||
x.indcollation::text || ' ' ||
coalesce(pg_get_expr(x.indexprs, x.indrelid), '') || ' ' ||
coalesce(pg_get_expr(x.indpred, x.indrelid), '')
pi.indrelid::text || ' ' || pi.indclass::text || ' ' || pi.indkey::text || ' ' ||
pi.indcollation::text || ' ' ||
coalesce(pg_get_expr(pi.indexprs, pi.indrelid), '') || ' ' ||
coalesce(pg_get_expr(pi.indpred, pi.indrelid), '')
) as grouping_key
from
pg_catalog.pg_index x
inner join pg_catalog.pg_class pc on pc.oid = x.indexrelid
pg_catalog.pg_index pi
inner join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
where
nsp.nspname = :schema_name_param::text and
Expand Down
20 changes: 10 additions & 10 deletions sql/indexes_with_null_values.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,21 +7,21 @@

-- Finds indexes that can contain null values.
select
i.indrelid::regclass::text as table_name,
i.indexrelid::regclass::text as index_name,
pi.indrelid::regclass::text as table_name,
pi.indexrelid::regclass::text as index_name,
string_agg(quote_ident(a.attname), ', ') as nullable_fields, /* in fact, there will always be only one column */
pg_relation_size(i.indexrelid) as index_size
pg_relation_size(pi.indexrelid) as index_size
from
pg_catalog.pg_index i
inner join pg_catalog.pg_class ic on ic.oid = i.indexrelid
pg_catalog.pg_index pi
inner join pg_catalog.pg_class ic on ic.oid = pi.indexrelid
inner join pg_catalog.pg_namespace nsp on nsp.oid = ic.relnamespace
inner join pg_catalog.pg_attribute a on a.attrelid = i.indrelid and a.attnum = any(i.indkey)
inner join pg_catalog.pg_attribute a on a.attrelid = pi.indrelid and a.attnum = any(pi.indkey)
where
not i.indisunique and
not pi.indisunique and
not a.attnotnull and
not ic.relispartition and
nsp.nspname = :schema_name_param::text and
array_position(i.indkey, a.attnum) = 0 and /* only for first segment */
(i.indpred is null or (position(lower(a.attname) in lower(pg_get_expr(i.indpred, i.indrelid))) = 0))
group by i.indrelid, i.indexrelid, i.indpred
array_position(pi.indkey, a.attnum) = 0 and /* only for first segment */
(pi.indpred is null or (position(lower(a.attname) in lower(pg_get_expr(pi.indpred, pi.indrelid))) = 0))
group by pi.indrelid, pi.indexrelid, pi.indpred
order by table_name, index_name;
36 changes: 36 additions & 0 deletions sql/indexes_with_unnecessary_where_clause.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
/*
* Copyright (c) 2019-2025. Ivan Vakhrushev and others.
* https://github.com/mfvanek/pg-index-health-sql
*
* Licensed under the Apache License 2.0
*/

-- Finds indexes that have a redundant predicate with the where-clause 'column is not null' for the not null column.
-- AL01
select
pc.oid::regclass::text as table_name,
pi.indexrelid::regclass::text as index_name,
pg_relation_size(pi.indexrelid) as index_size,
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by u.ordinality) as columns
from
pg_catalog.pg_index pi
inner join pg_catalog.pg_class pc on pc.oid = pi.indrelid
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
inner join unnest(pi.indkey) with ordinality u(attnum, ordinality) on true
inner join pg_catalog.pg_attribute a on a.attrelid = pc.oid and a.attnum = u.attnum
where
pc.relkind in ('r', 'p') and /* regular and partitioned tables */
not pc.relispartition and
pi.indpred is not null and
exists (
select 1
from
unnest(pi.indkey) k(attnum)
inner join pg_catalog.pg_attribute att on att.attrelid = pc.oid and att.attnum = k.attnum
where
att.attnotnull = true and
pg_get_indexdef(pi.indexrelid) ilike '%where%' || quote_ident(att.attname) || ' is not null%'
) and
nsp.nspname = :schema_name_param::text
group by pc.oid, pi.indexrelid
order by table_name, index_name;
11 changes: 6 additions & 5 deletions sql/invalid_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,12 +8,13 @@
-- Finds invalid indexes that might have appeared as a result of
-- unsuccessful execution of the 'create index concurrently' command.
select
x.indrelid::regclass::text as table_name,
x.indexrelid::regclass::text as index_name
pi.indrelid::regclass::text as table_name,
pi.indexrelid::regclass::text as index_name,
pg_relation_size(pi.indexrelid) as index_size
from
pg_catalog.pg_index x
inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = x.indexrelid
pg_catalog.pg_index pi
inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = pi.indexrelid
where
psai.schemaname = :schema_name_param::text and
x.indisvalid = false
pi.indisvalid = false
order by table_name, index_name;
17 changes: 9 additions & 8 deletions sql/primary_keys_with_varchar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,32 +14,33 @@
-- {b9b1f6f5-7f90-4b68-a389-f0ad8bb5784b} - with curly braces - 38 characters
select
pc.oid::regclass::text as table_name,
i.indexrelid::regclass as index_name,
pg_relation_size(i.indexrelid) as index_size,
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by a.attnum) as columns
pi.indexrelid::regclass as index_name,
pg_relation_size(pi.indexrelid) as index_size,
array_agg(quote_ident(a.attname) || ',' || a.attnotnull::text order by u.ordinality) as columns
from
pg_catalog.pg_class pc
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
inner join pg_catalog.pg_index i on i.indrelid = pc.oid
inner join pg_catalog.pg_attribute a on a.attrelid = pc.oid and a.attnum = any(i.indkey)
inner join pg_catalog.pg_index pi on pi.indrelid = pc.oid
inner join unnest(pi.indkey) with ordinality u(attnum, ordinality) on true
inner join pg_catalog.pg_attribute a on a.attrelid = pc.oid and a.attnum = u.attnum
where
not a.attisdropped and
a.attnum > 0 and
not pc.relispartition and
pc.relkind in ('r', 'p') and /* regular and partitioned tables */
i.indisprimary and
pi.indisprimary and
exists (
select 1
from
pg_catalog.pg_attribute a2
where
a2.attrelid = pc.oid and
a2.attnum = any(i.indkey) and
a2.attnum = any(pi.indkey) and
not a2.attisdropped and
a2.attnum > 0 and
a2.atttypid = any('{varchar,bpchar}'::regtype[]) and
(a2.atttypmod - 4) in (32, 36, 38)
) and
nsp.nspname = :schema_name_param::text
group by pc.oid, i.indexrelid
group by pc.oid, pi.indexrelid
order by table_name, index_name;
14 changes: 7 additions & 7 deletions sql/unused_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -20,26 +20,26 @@ with
),

foreign_key_indexes as (
select i.indexrelid
select pi.indexrelid
from
pg_catalog.pg_constraint c
inner join nsp on nsp.oid = c.connamespace
inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true
inner join pg_catalog.pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ i.indkey::int[])
inner join pg_catalog.pg_index pi on pi.indrelid = c.conrelid and (c.conkey::int[] <@ pi.indkey::int[])
where c.contype = 'f'
)

select
psui.relid::regclass::text as table_name,
psui.indexrelid::regclass::text as index_name,
psui.idx_scan as index_scans,
pg_relation_size(i.indexrelid) as index_size
pg_relation_size(pi.indexrelid) as index_size
from
pg_catalog.pg_stat_user_indexes psui
inner join pg_catalog.pg_index i on i.indexrelid = psui.indexrelid
inner join pg_catalog.pg_index pi on pi.indexrelid = psui.indexrelid
where
psui.schemaname in (select nspname from nsp) and
not i.indisunique and
i.indexrelid not in (select * from foreign_key_indexes) and /* retain indexes on foreign keys */
not pi.indisunique and
pi.indexrelid not in (select * from foreign_key_indexes) and /* retain indexes on foreign keys */
psui.idx_scan < 50::integer
order by table_name, pg_relation_size(i.indexrelid) desc;
order by table_name, pg_relation_size(pi.indexrelid) desc;