From eff28e3bf3e6d3f5a7566a36b399e39bf73727d0 Mon Sep 17 00:00:00 2001 From: Ivan Vakhrushev <37612014+mfvanek@users.noreply.github.com> Date: Thu, 19 Dec 2019 16:56:04 +0300 Subject: [PATCH] Explicitly specify pg_catalog for all sql queries #10 (#15) --- build.gradle | 2 +- .../maintenance/IndexMaintenanceImpl.java | 166 +++++++++--------- src/main/resources/sql/duplicated_indexes.sql | 4 +- .../sql/foreign_keys_without_index.sql | 18 +- .../sql/indexes_with_null_values.sql | 6 +- .../resources/sql/intersecting_indexes.sql | 8 +- src/main/resources/sql/invalid_indexes.sql | 10 +- .../sql/tables_with_missing_indexes.sql | 15 +- .../sql/tables_without_primary_key.sql | 14 +- src/main/resources/sql/unused_indexes.sql | 8 +- 10 files changed, 126 insertions(+), 125 deletions(-) diff --git a/build.gradle b/build.gradle index a00ca9e8..5ed52330 100644 --- a/build.gradle +++ b/build.gradle @@ -3,7 +3,7 @@ plugins { } group 'com.mfvanek' -version '0.0.3' +version '0.0.4' sourceCompatibility = 11 diff --git a/src/main/java/com/mfvanek/pg/index/maintenance/IndexMaintenanceImpl.java b/src/main/java/com/mfvanek/pg/index/maintenance/IndexMaintenanceImpl.java index 411e363e..1e3be78a 100644 --- a/src/main/java/com/mfvanek/pg/index/maintenance/IndexMaintenanceImpl.java +++ b/src/main/java/com/mfvanek/pg/index/maintenance/IndexMaintenanceImpl.java @@ -25,123 +25,125 @@ public class IndexMaintenanceImpl implements IndexMaintenance { private static final String INVALID_INDEXES_SQL = - "select x.indrelid::regclass as table_name, x.indexrelid::regclass as index_name\n" + - "from pg_index x\n" + - "join pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid\n" + - "where x.indisvalid = false and psai.schemaname = 'public'::text;"; + "select x.indrelid::regclass as table_name,\n" + + " x.indexrelid::regclass as index_name\n" + + "from pg_catalog.pg_index x\n" + + " join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid\n" + + "where psai.schemaname = 'public'::text\n" + + " and x.indisvalid = false;"; private static final String DUPLICATED_INDEXES_SQL = "select table_name,\n" + - " string_agg('idx=' || idx::text || ', size=' || pg_relation_size(idx), '; ') as duplicated_indexes\n" + + " string_agg('idx=' || idx::text || ', size=' || pg_relation_size(idx), '; ') as duplicated_indexes\n" + "from (\n" + - " select x.indexrelid::regclass as idx, x.indrelid::regclass as table_name,\n" + - " (x.indrelid::text ||' '|| x.indclass::text ||' '|| x.indkey::text ||' '||\n" + - " coalesce(pg_get_expr(x.indexprs, x.indrelid),'')||e' ' ||\n" + - " coalesce(pg_get_expr(x.indpred, x.indrelid),'')) as key\n" + - " from pg_index x\n" + - " join pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid\n" + - " where psai.schemaname = 'public'::text\n" + - " ) sub\n" + - "group by table_name, key having count(*) > 1\n" + + " select x.indexrelid::regclass as idx,\n" + + " x.indrelid::regclass as table_name,\n" + + " (x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' ||\n" + + " coalesce(pg_get_expr(x.indexprs, x.indrelid), '') || e' ' ||\n" + + " coalesce(pg_get_expr(x.indpred, x.indrelid), '')) as key\n" + + " from pg_catalog.pg_index x\n" + + " join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid\n" + + " where psai.schemaname = 'public'::text\n" + + ") sub\n" + + "group by table_name, key\n" + + "having count(*) > 1\n" + "order by table_name, sum(pg_relation_size(idx)) desc;"; private static final String INTERSECTED_INDEXES_SQL = "select a.indrelid::regclass as table_name,\n" + - " 'idx=' || a.indexrelid::regclass || ', size=' || pg_relation_size(a.indexrelid) || '; idx=' ||\n" + - " b.indexrelid::regclass || ', size=' || pg_relation_size(b.indexrelid) as intersected_indexes\n" + - "from (\n" + - " select *, array_to_string(indkey, ' ') as cols from pg_index) as a\n" + - " join (select *, array_to_string(indkey, ' ') as cols from pg_index) as b\n" + - " on (a.indrelid = b.indrelid and a.indexrelid > b.indexrelid and (\n" + - " (a.cols like b.cols||'%' and coalesce(substr(a.cols, length(b.cols)+1, 1), ' ') = ' ') or\n" + - " (b.cols like a.cols||'%' and coalesce(substr(b.cols, length(a.cols)+1, 1), ' ') = ' ')))\n" + + " 'idx=' || a.indexrelid::regclass || ', size=' || pg_relation_size(a.indexrelid) || '; idx=' || b.indexrelid::regclass || ', size=' || pg_relation_size(b.indexrelid) as intersected_indexes\n" + + "from\n" + + " (select *, array_to_string(indkey, ' ') as cols from pg_catalog.pg_index) as a\n" + + " join (select *, array_to_string(indkey, ' ') as cols from pg_catalog.pg_index) as b\n" + + " on (a.indrelid = b.indrelid and a.indexrelid > b.indexrelid and (\n" + + " (a.cols like b.cols || '%' and coalesce(substr(a.cols, length(b.cols) + 1, 1), ' ') = ' ') or\n" + + " (b.cols like a.cols || '%' and coalesce(substr(b.cols, length(a.cols) + 1, 1), ' ') = ' ')))\n" + + " join pg_catalog.pg_stat_all_indexes psai on a.indexrelid = psai.indexrelid\n" + + "where psai.schemaname = 'public'::text\n" + "order by a.indrelid::regclass::text;"; private static final String UNUSED_INDEXES_SQL = "with foreign_key_indexes as (\n" + " select i.indexrelid\n" + - " from pg_constraint c\n" + - " join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true\n" + - " join pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ indkey::int[])\n" + + " from pg_catalog.pg_constraint c\n" + + " join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true\n" + + " join pg_catalog.pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ i.indkey::int[])\n" + " where c.contype = 'f'\n" + ")\n" + "select psui.relname as table_name,\n" + - " psui.indexrelname as index_name,\n" + - " pg_relation_size(i.indexrelid) as index_size,\n" + - " psui.idx_scan as index_scans\n" + - "from pg_stat_user_indexes psui\n" + - " join pg_index i on psui.indexrelid = i.indexrelid\n" + - "where\n" + - " psui.schemaname = 'public'::text and not i.indisunique and\n" + - " i.indexrelid not in (select * from foreign_key_indexes) and /*retain indexes on foreign keys*/\n" + - " psui.idx_scan < 50::integer\n" + + " psui.indexrelname as index_name,\n" + + " pg_relation_size(i.indexrelid) as index_size,\n" + + " psui.idx_scan as index_scans\n" + + "from pg_catalog.pg_stat_user_indexes psui\n" + + " join pg_catalog.pg_index i on psui.indexrelid = i.indexrelid\n" + + "where psui.schemaname = 'public'::text\n" + + " and not i.indisunique\n" + + " and i.indexrelid not in (select * from foreign_key_indexes) /*retain indexes on foreign keys*/\n" + + " and psui.idx_scan < 50::integer\n" + "order by psui.relname, pg_relation_size(i.indexrelid) desc;"; private static final String FOREIGN_KEYS_WITHOUT_INDEX = "select c.conrelid::regclass as table_name,\n" + - " string_agg(col.attname, ', ' order by u.attposition) as columns,\n" + - " c.conname as constraint_name\n" + - "from pg_constraint c\n" + - " join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true\n" + - " join pg_class t on (c.conrelid = t.oid)\n" + - " join pg_namespace nsp on nsp.oid = t.relnamespace\n" + - " join pg_attribute col on (col.attrelid = t.oid and col.attnum = u.attnum)\n" + - "where contype = 'f' and\n" + - " nsp.nspname = 'public'::text and\n" + - " not exists (\n" + - " select 1 from pg_index\n" + - " where indrelid = c.conrelid and\n" + - " (c.conkey::int[] <@ indkey::int[]) and /*all columns of foreign key have to present in index*/\n" + - " array_position(indkey::int[], (c.conkey::int[])[1]) = 0 /*ordering of columns in foreign key and in index is the same*/\n" + - " )\n" + + " string_agg(col.attname, ', ' order by u.attposition) as columns,\n" + + " c.conname as constraint_name\n" + + "from pg_catalog.pg_constraint c\n" + + " join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true\n" + + " join pg_catalog.pg_class t on (c.conrelid = t.oid)\n" + + " join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace\n" + + " join pg_catalog.pg_attribute col on (col.attrelid = t.oid and col.attnum = u.attnum)\n" + + "where c.contype = 'f'\n" + + " and nsp.nspname = 'public'::text\n" + + " and not exists(\n" + + " select 1\n" + + " from pg_catalog.pg_index pi\n" + + " where pi.indrelid = c.conrelid\n" + + " and (c.conkey::int[] <@ pi.indkey::int[]) /*all columns of foreign key have to present in index*/\n" + + " and array_position(pi.indkey::int[], (c.conkey::int[])[1]) = 0 /*ordering of columns in foreign key and in index is the same*/\n" + + " )\n" + "group by c.conrelid, c.conname, c.oid\n" + "order by (c.conrelid::regclass)::text, columns;"; private static final String TABLES_WITH_MISSING_INDEXES = "with tables_without_indexes as (\n" + - " select\n" + - " relname::text as table_name,\n" + - " coalesce(seq_scan, 0) - coalesce(idx_scan, 0) as too_much_seq,\n" + - " pg_relation_size(relname::regclass) as table_size,\n" + - " coalesce(seq_scan, 0) as seq_scan,\n" + - " coalesce(idx_scan, 0) as idx_scan\n" + - " from pg_stat_all_tables\n" + - " where\n" + - " schemaname = 'public'::text and\n" + - " pg_relation_size(relname::regclass) > 5::integer * 8192 /*skip small tables*/\n" + + " select psat.relname::text as table_name,\n" + + " coalesce(psat.seq_scan, 0) - coalesce(psat.idx_scan, 0) as too_much_seq,\n" + + " coalesce(psat.seq_scan, 0) as seq_scan,\n" + + " coalesce(psat.idx_scan, 0) as idx_scan\n" + + " from pg_catalog.pg_stat_all_tables psat\n" + + " where psat.schemaname = 'public'::text\n" + + " and pg_relation_size(psat.relname::regclass) > 5::integer * 8192 /*skip small tables*/\n" + ")\n" + "select table_name,\n" + - " seq_scan,\n" + - " idx_scan\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" + + "where (seq_scan + idx_scan) > 100::integer /*table in use*/\n" + + " and too_much_seq > 0 /*too much sequential scans*/\n" + "order by table_name, too_much_seq desc;"; 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 pt.tablename as table_name\n" + + "from pg_catalog.pg_tables pt\n" + + "where pt.schemaname = 'public'::text\n" + + " and pt.tablename not in (\n" + " select c.conrelid::regclass::text as table_name\n" + - " from pg_constraint c\n" + - " where contype = 'p')\n" + - "order by tablename;"; + " from pg_catalog.pg_constraint c\n" + + " where c.contype = 'p')\n" + + "order by pt.tablename;"; private static final String INDEXES_WITH_NULL_VALUES = "select x.indrelid::regclass as table_name,\n" + - " x.indexrelid::regclass as index_name,\n" + - " string_agg(a.attname, ', ') as nullable_fields,\n" + - " pg_relation_size(x.indexrelid) as index_size\n" + - "from pg_index x\n" + - " join pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid\n" + - " join pg_attribute a ON a.attrelid = x.indrelid AND a.attnum = any(x.indkey)\n" + - "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" + - " (x.indpred is null or (position(lower(a.attname) in lower(pg_get_expr(x.indpred, x.indrelid))) = 0))\n" + + " x.indexrelid::regclass as index_name,\n" + + " string_agg(a.attname, ', ') as nullable_fields,\n" + + " pg_relation_size(x.indexrelid) as index_size\n" + + "from pg_catalog.pg_index x\n" + + " join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid\n" + + " join pg_catalog.pg_attribute a ON a.attrelid = x.indrelid AND a.attnum = any(x.indkey)\n" + + "where not x.indisunique\n" + + " and not a.attnotnull\n" + + " and psai.schemaname = 'public'::text\n" + + " and array_position(x.indkey, a.attnum) = 0 /*only for first segment*/\n" + + " and (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;"; diff --git a/src/main/resources/sql/duplicated_indexes.sql b/src/main/resources/sql/duplicated_indexes.sql index 33b08659..f3b5a44a 100644 --- a/src/main/resources/sql/duplicated_indexes.sql +++ b/src/main/resources/sql/duplicated_indexes.sql @@ -6,8 +6,8 @@ from ( (x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' || coalesce(pg_get_expr(x.indexprs, x.indrelid), '') || e' ' || coalesce(pg_get_expr(x.indpred, x.indrelid), '')) as key - from pg_index x - join pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid + from pg_catalog.pg_index x + join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid where psai.schemaname = 'public'::text ) sub group by table_name, key diff --git a/src/main/resources/sql/foreign_keys_without_index.sql b/src/main/resources/sql/foreign_keys_without_index.sql index fc1c068e..42ed2912 100644 --- a/src/main/resources/sql/foreign_keys_without_index.sql +++ b/src/main/resources/sql/foreign_keys_without_index.sql @@ -1,19 +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 +from pg_catalog.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' + join pg_catalog.pg_class t on (c.conrelid = t.oid) + join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace + join pg_catalog.pg_attribute col on (col.attrelid = t.oid and col.attnum = u.attnum) +where c.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*/ + from pg_catalog.pg_index pi + where pi.indrelid = c.conrelid + and (c.conkey::int[] <@ pi.indkey::int[]) /*all columns of foreign key have to present in index*/ + and array_position(pi.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; diff --git a/src/main/resources/sql/indexes_with_null_values.sql b/src/main/resources/sql/indexes_with_null_values.sql index fca5d997..507e88ca 100644 --- a/src/main/resources/sql/indexes_with_null_values.sql +++ b/src/main/resources/sql/indexes_with_null_values.sql @@ -2,9 +2,9 @@ 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) +from pg_catalog.pg_index x + join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid + join pg_catalog.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 diff --git a/src/main/resources/sql/intersecting_indexes.sql b/src/main/resources/sql/intersecting_indexes.sql index 17c6ba6f..ed5a2d68 100644 --- a/src/main/resources/sql/intersecting_indexes.sql +++ b/src/main/resources/sql/intersecting_indexes.sql @@ -1,11 +1,11 @@ select a.indrelid::regclass as table_name, 'idx=' || a.indexrelid::regclass || ', size=' || pg_relation_size(a.indexrelid) || '; idx=' || b.indexrelid::regclass || ', size=' || pg_relation_size(b.indexrelid) as intersected_indexes -from ( - select *, array_to_string(indkey, ' ') as cols - from pg_index) as a - join (select *, array_to_string(indkey, ' ') as cols from pg_index) as b +from (select *, array_to_string(indkey, ' ') as cols from pg_catalog.pg_index) as a + join (select *, array_to_string(indkey, ' ') as cols from pg_catalog.pg_index) as b on (a.indrelid = b.indrelid and a.indexrelid > b.indexrelid and ( (a.cols like b.cols || '%' and coalesce(substr(a.cols, length(b.cols) + 1, 1), ' ') = ' ') or (b.cols like a.cols || '%' and coalesce(substr(b.cols, length(a.cols) + 1, 1), ' ') = ' '))) + join pg_catalog.pg_stat_all_indexes psai on a.indexrelid = psai.indexrelid +where psai.schemaname = 'public'::text order by a.indrelid::regclass::text; diff --git a/src/main/resources/sql/invalid_indexes.sql b/src/main/resources/sql/invalid_indexes.sql index 528a33d6..e8577416 100644 --- a/src/main/resources/sql/invalid_indexes.sql +++ b/src/main/resources/sql/invalid_indexes.sql @@ -1,6 +1,6 @@ -select - x.indrelid::regclass as table_name, +select x.indrelid::regclass as table_name, x.indexrelid::regclass as index_name -from pg_index x -join pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid and psai.schemaname = 'public'::text -where x.indisvalid = false; +from pg_catalog.pg_index x + join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid +where psai.schemaname = 'public'::text + and x.indisvalid = false; diff --git a/src/main/resources/sql/tables_with_missing_indexes.sql b/src/main/resources/sql/tables_with_missing_indexes.sql index 603420ba..418e7ce1 100644 --- a/src/main/resources/sql/tables_with_missing_indexes.sql +++ b/src/main/resources/sql/tables_with_missing_indexes.sql @@ -1,12 +1,11 @@ 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 psat.relname::text as table_name, + coalesce(psat.seq_scan, 0) - coalesce(psat.idx_scan, 0) as too_much_seq, + coalesce(psat.seq_scan, 0) as seq_scan, + coalesce(psat.idx_scan, 0) as idx_scan + from pg_catalog.pg_stat_all_tables psat + where psat.schemaname = 'public'::text + and pg_relation_size(psat.relname::regclass) > 5::integer * 8192 /*skip small tables*/ ) select table_name, seq_scan, diff --git a/src/main/resources/sql/tables_without_primary_key.sql b/src/main/resources/sql/tables_without_primary_key.sql index 673b8838..91702592 100644 --- a/src/main/resources/sql/tables_without_primary_key.sql +++ b/src/main/resources/sql/tables_without_primary_key.sql @@ -1,8 +1,8 @@ -select tablename as table_name -from pg_tables -where schemaname = 'public'::text - and tablename not in ( +select pt.tablename as table_name +from pg_catalog.pg_tables pt +where pt.schemaname = 'public'::text + and pt.tablename not in ( select c.conrelid::regclass::text as table_name - from pg_constraint c - where contype = 'p') -order by tablename; + from pg_catalog.pg_constraint c + where c.contype = 'p') +order by pt.tablename; diff --git a/src/main/resources/sql/unused_indexes.sql b/src/main/resources/sql/unused_indexes.sql index effa33dc..f1179b22 100644 --- a/src/main/resources/sql/unused_indexes.sql +++ b/src/main/resources/sql/unused_indexes.sql @@ -1,16 +1,16 @@ with foreign_key_indexes as ( select i.indexrelid - from pg_constraint c + from pg_catalog.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[]) + join pg_catalog.pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ i.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 +from pg_catalog.pg_stat_user_indexes psui + join pg_catalog.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*/