forked from mfvanek/pg-index-health-sql
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Raw sql queries and tests (mfvanek#6)
* Added raw sql queries * Added all sql queries in raw format * Added links for queries into README.md * Added unit tests for IndexesHealthImpl
- Loading branch information
Showing
10 changed files
with
279 additions
and
19 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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,19 @@ | ||
select c.conrelid::regclass as table_name, | ||
string_agg(col.attname, ', ' order by u.attposition) as columns, | ||
c.conname as constraint_name | ||
from pg_constraint c | ||
join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true | ||
join pg_class t on (c.conrelid = t.oid) | ||
join pg_namespace nsp on nsp.oid = t.relnamespace | ||
join pg_attribute col on (col.attrelid = t.oid and col.attnum = u.attnum) | ||
where contype = 'f' | ||
and nsp.nspname = 'public'::text | ||
and not exists( | ||
select 1 | ||
from pg_index | ||
where indrelid = c.conrelid | ||
and (c.conkey::int[] <@ indkey::int[]) /*all columns of foreign key have to present in index*/ | ||
and array_position(indkey::int[], (c.conkey::int[])[1]) = 0 /*ordering of columns in foreign key and in index is the same*/ | ||
) | ||
group by c.conrelid, c.conname, c.oid | ||
order by (c.conrelid::regclass)::text, columns; |
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,14 @@ | ||
select x.indrelid::regclass as table_name, | ||
x.indexrelid::regclass as index_name, | ||
string_agg(a.attname, ', ') as nullable_fields, | ||
pg_relation_size(x.indexrelid) as index_size | ||
from pg_index x | ||
join pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid | ||
join pg_attribute a ON a.attrelid = x.indrelid AND a.attnum = any (x.indkey) | ||
where not x.indisunique | ||
and not a.attnotnull | ||
and psai.schemaname = 'public'::text | ||
and array_position(x.indkey, a.attnum) = 0 /*only for first segment*/ | ||
and (x.indpred is null or (position(lower(a.attname) in lower(pg_get_expr(x.indpred, x.indrelid))) = 0)) | ||
group by x.indrelid, x.indexrelid, x.indpred | ||
order by table_name, index_name; |
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,17 @@ | ||
with tables_without_indexes as ( | ||
select relname::text as table_name, | ||
coalesce(seq_scan, 0) - coalesce(idx_scan, 0) as too_much_seq, | ||
pg_relation_size(relname::regclass) as table_size, | ||
coalesce(seq_scan, 0) as seq_scan, | ||
coalesce(idx_scan, 0) as idx_scan | ||
from pg_stat_all_tables | ||
where schemaname = 'public'::text | ||
and pg_relation_size(relname::regclass) > 5::integer * 8192 /*skip small tables*/ | ||
) | ||
select table_name, | ||
seq_scan, | ||
idx_scan | ||
from tables_without_indexes | ||
where (seq_scan + idx_scan) > 100::integer /*table in use*/ | ||
and too_much_seq > 0 /*too much sequential scans*/ | ||
order by table_name, too_much_seq desc; |
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,8 @@ | ||
select tablename as table_name | ||
from pg_tables | ||
where schemaname = 'public'::text | ||
and tablename not in ( | ||
select c.conrelid::regclass::text as table_name | ||
from pg_constraint c | ||
where contype = 'p') | ||
order by tablename; |
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,20 @@ | ||
with foreign_key_indexes as ( | ||
select i.indexrelid | ||
from pg_constraint c | ||
join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true | ||
join pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ indkey::int[]) | ||
where c.contype = 'f' | ||
) | ||
select psui.relname as table_name, | ||
psui.indexrelname as index_name, | ||
pg_relation_size(i.indexrelid) as index_size, | ||
psui.idx_scan as index_scans | ||
from pg_stat_user_indexes psui | ||
join pg_index i on psui.indexrelid = i.indexrelid | ||
where psui.schemaname = 'public'::text | ||
and not i.indisunique | ||
and i.indexrelid not in (select * from foreign_key_indexes) /*retain indexes on foreign keys*/ | ||
and psui.idx_scan < 50::integer | ||
and pg_relation_size(psui.relid) >= 5::integer * 8192 /*skip small tables*/ | ||
and pg_relation_size(psui.indexrelid) >= 5::integer * 8192 /*skip small indexes*/ | ||
order by psui.relname, pg_relation_size(i.indexrelid) desc; |
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
Oops, something went wrong.