-
Notifications
You must be signed in to change notification settings - Fork 10
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
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 <khizhinvadim@gmail.com>
- Loading branch information
Showing
5 changed files
with
30 additions
and
5 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |