Skip to content

Commit

Permalink
Query to find B-tree indexes on array columns (#35)
Browse files Browse the repository at this point in the history
* Query to find B-tree indexes on array columns

* Bump super-linter from slim-v5 to slim-v6

* Rewrite query

* Minor improvements

---------

Co-authored-by: Vadim Khizhin <khizhinvadim@gmail.com>
  • Loading branch information
mfaulther and Vadim Khizhin authored Apr 25, 2024
1 parent 521f893 commit 7d9e0c6
Show file tree
Hide file tree
Showing 5 changed files with 30 additions and 5 deletions.
2 changes: 1 addition & 1 deletion .github/linters/.sqlfluff
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
[sqlfluff]
dialect = postgres
exclude_rules = LT01, LT02, LT03, LT08, AM03, AM05, AL01, AL05, ST06
exclude_rules = LT01, LT02, LT03, LT08, AM03, AM05, AL01, AL05, ST06, ST09
warnings = AM06, ST05
max_line_length = 180
templater = raw
Expand Down
2 changes: 1 addition & 1 deletion .github/workflows/linter.yml
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@ jobs:
fetch-depth: 0

- name: Lint Code Base
uses: github/super-linter/slim@v5
uses: github/super-linter/slim@v6
env:
VALIDATE_ALL_CODEBASE: false
VALIDATE_SQLFLUFF: true
Expand Down
3 changes: 1 addition & 2 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -44,8 +44,7 @@ To run super-linter locally
docker run \
-e RUN_LOCAL=true \
-e USE_FIND_ALGORITHM=true \
-e VALIDATE_ALL_CODEBASE=false \
-e VALIDATE_SQLFLUFF=true \
-v $(pwd):/tmp/lint \
github/super-linter:slim-v5
ghcr.io/super-linter/super-linter:slim-v6
```
2 changes: 1 addition & 1 deletion sql/bloated_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -57,7 +57,7 @@ named_indexes_attributes as (
ic.inner_index_name,
ic.attpos,
ic.indkey,
ic.indkey[ic.attpos],
ic.indkey[ic.attpos] as indattpos,
ic.reltuples,
ic.relpages,
ic.index_oid,
Expand Down
26 changes: 26 additions & 0 deletions sql/btree_indexes_on_array_columns.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
/*
* Copyright (c) 2019-2024. Ivan Vakhrushev and others.
* https://github.com/mfvanek/pg-index-health-sql
*
* Licensed under the Apache License 2.0
*/

-- Finds B-tree indexes on array columns
--
-- GIN-index should be used instead for such columns
-- Based on query from https://habr.com/ru/articles/800121/
select
i.indrelid::regclass as table_name, -- Name of the table
i.indexrelid::regclass as index_name, -- Name of the index
col.attname as column_name, -- Column name
col.attnotnull as column_not_null -- Column not null
from pg_catalog.pg_index as i
inner join pg_catalog.pg_class as ic on i.indexrelid = ic.oid
inner join pg_catalog.pg_namespace as nsp on nsp.oid = ic.relnamespace
inner join pg_catalog.pg_am as a on ic.relam = a.oid and a.amname = 'btree'
inner join pg_catalog.pg_attribute as col on i.indrelid = col.attrelid and col.attnum = any((string_to_array(i.indkey::text, ' ')::int2[])[:i.indnkeyatts])
inner join pg_catalog.pg_type as typ on typ.oid = col.atttypid
where
nsp.nspname = :schema_name_param::text and
typ.typcategory = 'A' -- A stands for Array type. See - https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
order by ic.oid::regclass::text, i.indexrelid::regclass::text;

0 comments on commit 7d9e0c6

Please sign in to comment.