Skip to content

Commit

Permalink
Raw sql queries and tests (mfvanek#6)
Browse files Browse the repository at this point in the history
* 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
mfvanek authored Dec 6, 2019
1 parent b06c194 commit 7908aa9
Show file tree
Hide file tree
Showing 10 changed files with 279 additions and 19 deletions.
16 changes: 8 additions & 8 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,14 +6,14 @@

## Available checks
**pg-index-health** allows you to detect the following problems:
1. Invalid (broken) indexes.
1. Duplicated (completely identical) indexes.
1. Intersecting (partially identical) indexes.
1. Unused indexes.
1. Foreign keys without associated indexes.
1. Indexes with null values.
1. Tables with missing indexes.
1. Tables without primary key.
1. Invalid (broken) indexes ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/invalid_indexes.sql)).
1. Duplicated (completely identical) indexes ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/duplicated_indexes.sql)).
1. Intersecting (partially identical) indexes ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/intersecting_indexes.sql)).
1. Unused indexes ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/unused_indexes.sql)).
1. Foreign keys without associated indexes ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/foreign_keys_without_index.sql)).
1. Indexes with null values ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/indexes_with_null_values.sql)).
1. Tables with missing indexes ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/tables_with_missing_indexes.sql)).
1. Tables without primary key ([sql](https://github.com/mfvanek/pg-index-health/blob/master/src/main/resources/sql/tables_without_primary_key.sql)).

## Demo application
```java
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -34,7 +34,7 @@ public Set<PgConnection> getConnectionsToReplicas() {

@Nonnull
public static HighAvailabilityPgConnection of(@Nonnull final PgConnection connectionToMaster) {
return new HighAvailabilityPgConnectionImpl(connectionToMaster, Set.of());
return new HighAvailabilityPgConnectionImpl(connectionToMaster, Set.of(connectionToMaster));
}

@Nonnull
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -117,27 +117,25 @@ public class IndexMaintenanceImpl implements IndexMaintenance {
" from pg_stat_all_tables\n" +
" where\n" +
" schemaname = 'public'::text and\n" +
" pg_relation_size(relname::regclass) > 5::integer * 8192 and /*skip small tables*/\n" +
" relname not in ('databasechangelog')\n" +
" pg_relation_size(relname::regclass) > 5::integer * 8192 /*skip small tables*/\n" +
")\n" +
"select table_name,\n" +
" seq_scan,\n" +
" idx_scan\n" +
"from tables_without_indexes\n" +
"where (seq_scan + idx_scan) > 100::integer and /*table in use*/\n" +
" too_much_seq > 0 -- too much sequential scans\n" +
" too_much_seq > 0 /*too much sequential scans*/\n" +
"order by table_name, too_much_seq desc;";

private static final String TABLES_WITHOUT_PRIMARY_KEYS =
private static final String TABLES_WITHOUT_PRIMARY_KEY =
"select tablename as table_name\n" +
"from pg_tables\n" +
"where\n" +
" schemaname = 'public'::text and\n" +
" tablename not in (\n" +
" select c.conrelid::regclass::text as table_name\n" +
" from pg_constraint c\n" +
" where contype = 'p') and\n" +
" tablename not in ('databasechangelog')\n" +
" where contype = 'p')\n" +
"order by tablename;";

private static final String INDEXES_WITH_NULL_VALUES =
Expand All @@ -151,7 +149,7 @@ public class IndexMaintenanceImpl implements IndexMaintenance {
"where not x.indisunique and\n" +
" not a.attnotnull and\n" +
" psai.schemaname = 'public'::text and\n" +
" array_position(x.indkey, a.attnum) = 0 and -- only for first segment\n" +
" array_position(x.indkey, a.attnum) = 0 and /*only for first segment*/\n" +
" (x.indpred is null or (position(lower(a.attname) in lower(pg_get_expr(x.indpred, x.indrelid))) = 0))\n" +
"group by x.indrelid, x.indexrelid, x.indpred\n" +
"order by table_name, index_name;";
Expand Down Expand Up @@ -222,7 +220,7 @@ public List<TableWithMissingIndex> getTablesWithMissingIndexes() {
@Nonnull
@Override
public List<TableWithoutPrimaryKey> getTablesWithoutPrimaryKey() {
return executeQuery(TABLES_WITHOUT_PRIMARY_KEYS, rs -> {
return executeQuery(TABLES_WITHOUT_PRIMARY_KEY, rs -> {
final String tableName = rs.getString("table_name");
return TableWithoutPrimaryKey.of(tableName);
});
Expand Down
19 changes: 19 additions & 0 deletions src/main/resources/sql/foreign_keys_without_index.sql
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;
14 changes: 14 additions & 0 deletions src/main/resources/sql/indexes_with_null_values.sql
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;
17 changes: 17 additions & 0 deletions src/main/resources/sql/tables_with_missing_indexes.sql
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;
8 changes: 8 additions & 0 deletions src/main/resources/sql/tables_without_primary_key.sql
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;
20 changes: 20 additions & 0 deletions src/main/resources/sql/unused_indexes.sql
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;
Original file line number Diff line number Diff line change
Expand Up @@ -10,8 +10,12 @@
import org.junit.jupiter.api.Test;
import org.junit.jupiter.api.extension.RegisterExtension;

import java.util.Set;

import static org.hamcrest.MatcherAssert.assertThat;
import static org.hamcrest.Matchers.containsInAnyOrder;
import static org.hamcrest.Matchers.hasSize;
import static org.junit.jupiter.api.Assertions.assertEquals;
import static org.junit.jupiter.api.Assertions.assertNotNull;

class HighAvailabilityPgConnectionImplTest {
Expand All @@ -26,6 +30,17 @@ void ofMaster() {
final var pgConnection = PgConnectionImpl.ofMaster(embeddedPostgres.getTestDatabase());
final var haPgConnection = HighAvailabilityPgConnectionImpl.of(pgConnection);
assertNotNull(haPgConnection);
assertThat(haPgConnection.getConnectionsToReplicas(), hasSize(0));
assertThat(haPgConnection.getConnectionsToReplicas(), hasSize(1));
assertEquals(haPgConnection.getConnectionToMaster(), haPgConnection.getConnectionsToReplicas().iterator().next());
}

@Test
void withReplicas() {
final var master = PgConnectionImpl.ofMaster(embeddedPostgres.getTestDatabase());
final var replica = PgConnectionImpl.of(embeddedPostgres.getTestDatabase(), PgHostImpl.ofName("replica"));
final var haPgConnection = HighAvailabilityPgConnectionImpl.of(master, Set.of(master, replica));
assertNotNull(haPgConnection);
assertThat(haPgConnection.getConnectionsToReplicas(), hasSize(2));
assertThat(haPgConnection.getConnectionsToReplicas(), containsInAnyOrder(master, replica));
}
}
Loading

0 comments on commit 7908aa9

Please sign in to comment.