Skip to content

Commit 7d9e0c6

Browse files
mfaultherVadim Khizhin
and
Vadim Khizhin
authored
Query to find B-tree indexes on array columns (#35)
* 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 <[email protected]>
1 parent 521f893 commit 7d9e0c6

File tree

5 files changed

+30
-5
lines changed

5 files changed

+30
-5
lines changed

.github/linters/.sqlfluff

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
[sqlfluff]
22
dialect = postgres
3-
exclude_rules = LT01, LT02, LT03, LT08, AM03, AM05, AL01, AL05, ST06
3+
exclude_rules = LT01, LT02, LT03, LT08, AM03, AM05, AL01, AL05, ST06, ST09
44
warnings = AM06, ST05
55
max_line_length = 180
66
templater = raw

.github/workflows/linter.yml

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -18,7 +18,7 @@ jobs:
1818
fetch-depth: 0
1919

2020
- name: Lint Code Base
21-
uses: github/super-linter/slim@v5
21+
uses: github/super-linter/slim@v6
2222
env:
2323
VALIDATE_ALL_CODEBASE: false
2424
VALIDATE_SQLFLUFF: true

README.md

Lines changed: 1 addition & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -44,8 +44,7 @@ To run super-linter locally
4444
docker run \
4545
-e RUN_LOCAL=true \
4646
-e USE_FIND_ALGORITHM=true \
47-
-e VALIDATE_ALL_CODEBASE=false \
4847
-e VALIDATE_SQLFLUFF=true \
4948
-v $(pwd):/tmp/lint \
50-
github/super-linter:slim-v5
49+
ghcr.io/super-linter/super-linter:slim-v6
5150
```

sql/bloated_indexes.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -57,7 +57,7 @@ named_indexes_attributes as (
5757
ic.inner_index_name,
5858
ic.attpos,
5959
ic.indkey,
60-
ic.indkey[ic.attpos],
60+
ic.indkey[ic.attpos] as indattpos,
6161
ic.reltuples,
6262
ic.relpages,
6363
ic.index_oid,
Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,26 @@
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 B-tree indexes on array columns
9+
--
10+
-- GIN-index should be used instead for such columns
11+
-- Based on query from https://habr.com/ru/articles/800121/
12+
select
13+
i.indrelid::regclass as table_name, -- Name of the table
14+
i.indexrelid::regclass as index_name, -- Name of the index
15+
col.attname as column_name, -- Column name
16+
col.attnotnull as column_not_null -- Column not null
17+
from pg_catalog.pg_index as i
18+
inner join pg_catalog.pg_class as ic on i.indexrelid = ic.oid
19+
inner join pg_catalog.pg_namespace as nsp on nsp.oid = ic.relnamespace
20+
inner join pg_catalog.pg_am as a on ic.relam = a.oid and a.amname = 'btree'
21+
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])
22+
inner join pg_catalog.pg_type as typ on typ.oid = col.atttypid
23+
where
24+
nsp.nspname = :schema_name_param::text and
25+
typ.typcategory = 'A' -- A stands for Array type. See - https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
26+
order by ic.oid::regclass::text, i.indexrelid::regclass::text;

0 commit comments

Comments
 (0)