diff --git a/sql/index_candidates_to_deduplicate.sql b/sql/index_candidates_to_deduplicate.sql index d1f53b5..e2b0cbe 100644 --- a/sql/index_candidates_to_deduplicate.sql +++ b/sql/index_candidates_to_deduplicate.sql @@ -11,9 +11,9 @@ SELECT n.nspname AS schema_name, replace(pg_get_indexdef(i.oid), 'CREATE INDEX ', '') AS index_def, (SELECT array_agg(round(f::numeric,4)) FROM ( - SELECT max(null_frac) + (1 - max(null_frac))*SUM(u) AS f FROM pg_attribute a JOIN pg_stats s ON (s.schemaname = n.nspname AND s.tablename = c.relname AND s.attname = a.attname) LEFT JOIN LATERAL unnest(s.most_common_freqs) u ON TRUE WHERE a.attrelid = x.indrelid AND a.attnum = ANY(x.indkey) GROUP BY a.attnum + (SELECT max(null_frac) + (1 - max(null_frac))*SUM(u) AS f FROM pg_attribute a JOIN pg_stats s ON (s.schemaname = n.nspname AND s.tablename = c.relname AND s.attname = a.attname) LEFT JOIN LATERAL unnest(s.most_common_freqs) u ON TRUE WHERE a.attrelid = x.indrelid AND a.attnum = ANY(x.indkey) GROUP BY a.attnum ORDER BY array_position(x.indkey, a.attnum)) UNION ALL - SELECT max(null_frac) + (1 - max(null_frac))*SUM(u2) AS f FROM pg_stats s2 LEFT JOIN LATERAL unnest(s2.most_common_freqs) u2 ON true WHERE s2.schemaname = n.nspname AND s2.tablename = i.relname GROUP BY s2.attname + (SELECT max(null_frac) + (1 - max(null_frac))*SUM(u2) AS f FROM pg_stats s2 LEFT JOIN LATERAL unnest(s2.most_common_freqs) u2 ON true WHERE s2.schemaname = n.nspname AND s2.tablename = i.relname GROUP BY s2.attname) ) t ) AS sum_most_common_freqs FROM pg_index x diff --git a/sql/indexing_progress.sql b/sql/indexing_progress.sql index e7fce49..044523d 100644 --- a/sql/indexing_progress.sql +++ b/sql/indexing_progress.sql @@ -1,15 +1,14 @@ -- List active indexing sessions and their progress SELECT p.pid - , date_trunc('second',now() - a.xact_start) AS dur - , coalesce(wait_event_type ||'.'|| wait_event, 'f') AS wait - , p.datname - , p.index_relid::regclass AS ind - , round(pg_total_relation_size(index_relid)/1024.0/1024) AS ind_ttl_mb + , date_trunc('second',now() - a.xact_start) AS duration + , p.datname AS database + , p.index_relid::regclass AS index + , pg_size_pretty(pg_total_relation_size(index_relid)) || ' / ' || coalesce(pg_size_pretty(pg_total_relation_size((SELECT DISTINCT indexrelid FROM pg_locks l JOIN pg_index i ON l.relation = i.indexrelid WHERE l.pid = p.pid AND l.locktype = 'relation' AND i.indexrelid != p.index_relid))), '-') AS "new / old size" , p.command, p.phase + , CASE WHEN blocks_total > 0 THEN format('%s%% of %s', round(blocks_done::numeric / blocks_total * 100, 1), blocks_total) END AS blocks + , CASE WHEN tuples_total > 0 THEN format('%s%% of %s', round(tuples_done::numeric / tuples_total * 100, 1), tuples_total) END AS tuples + , (SELECT COUNT(*) FROM pg_stat_activity a2 where a2.query = a.query) AS workers , CASE WHEN lockers_total > lockers_done AND p.phase ~ 'waiting' THEN format('%s ( %s / %s )', current_locker_pid, lockers_done, lockers_total) END AS waiting - , CASE WHEN blocks_total > 0 THEN format('%s%% of %s', round(blocks_done::numeric / blocks_total * 100), blocks_total) END AS blocks - , CASE WHEN tuples_total > 0 THEN format('%s%% of %s', round(tuples_done::numeric / tuples_total * 100), tuples_total) END AS tuples - , CASE WHEN partitions_total > 0 THEN format('%s%% of %s', round(partitions_done::numeric / partitions_total * 100), partitions_total) END AS partitions - FROM pg_stat_progress_create_index p JOIN pg_stat_activity a using (pid) ORDER BY dur DESC; - + , coalesce(wait_event_type ||'.'|| wait_event, 'f') AS wait_event + FROM pg_stat_progress_create_index p JOIN pg_stat_activity a using (pid) ORDER BY duration DESC; \ No newline at end of file