|
| 1 | +--Load Profile |
| 2 | + |
| 3 | +with data as ( |
| 4 | + select |
| 5 | + s.relname as table_name, |
| 6 | + s.schemaname as schema_name, |
| 7 | + (select spcname from pg_tablespace where oid = reltablespace) as tblspace, |
| 8 | + *, |
| 9 | + case when n_tup_upd = 0 then null else n_tup_hot_upd::numeric / n_tup_upd end as upd_hot_ratio, |
| 10 | + seq_tup_read + coalesce(idx_tup_fetch, 0) - n_tup_del - n_tup_upd as tuples_selected, |
| 11 | + seq_tup_read + coalesce(idx_tup_fetch, 0) + n_tup_ins as processed_tup_total -- we don't add _del and _upd here (already counted via seq_ & idx_) |
| 12 | + from pg_stat_user_tables s |
| 13 | + join pg_class c on c.oid = relid |
| 14 | +), data2 as ( |
| 15 | + select |
| 16 | + 0 as ord, |
| 17 | + '*** TOTAL ***' as table_name, |
| 18 | + null as schema_name, |
| 19 | + null as tblspace, |
| 20 | + sum(seq_tup_read) as seq_tup_read, |
| 21 | + sum(idx_tup_fetch) as idx_tup_fetch, |
| 22 | + sum(tuples_selected) as tuples_selected, |
| 23 | + sum(n_tup_ins) as n_tup_ins, |
| 24 | + sum(n_tup_del) as n_tup_del, |
| 25 | + sum(n_tup_upd) as n_tup_upd, |
| 26 | + sum(n_tup_hot_upd) as n_tup_hot_upd, |
| 27 | + avg(upd_hot_ratio) as upd_hot_ratio, |
| 28 | + sum(processed_tup_total) as processed_tup_total |
| 29 | + from data |
| 30 | + union all |
| 31 | + select |
| 32 | + 1 as ord, |
| 33 | + ' tablespace: [' || coalesce(tblspace, 'pg_default') || ']' as table_name, |
| 34 | + null as schema_name, |
| 35 | + null, -- we don't need to pass real tblspace value for this aggregated record further |
| 36 | + sum(seq_tup_read) as seq_tup_read, |
| 37 | + sum(idx_tup_fetch) as idx_tup_fetch, |
| 38 | + sum(tuples_selected) as tuples_selected, |
| 39 | + sum(n_tup_ins) as n_tup_ins, |
| 40 | + sum(n_tup_del) as n_tup_del, |
| 41 | + sum(n_tup_upd) as n_tup_upd, |
| 42 | + sum(n_tup_hot_upd) as n_tup_hot_upd, |
| 43 | + avg(upd_hot_ratio) as upd_hot_ratio, |
| 44 | + sum(processed_tup_total) as processed_tup_total |
| 45 | + from data |
| 46 | + where (select count(distinct coalesce(tblspace, 'pg_default')) from data) > 1 -- don't show this part if there are no custom tablespaces |
| 47 | + group by tblspace |
| 48 | + union all |
| 49 | + select 3, null, null, null, null, null, null, null, null, null, null, null, null |
| 50 | + union all |
| 51 | + select 4, table_name, schema_name, tblspace, seq_tup_read, idx_tup_fetch, tuples_selected, n_tup_ins, n_tup_del, n_tup_upd, n_tup_hot_upd, upd_hot_ratio, processed_tup_total |
| 52 | + from data |
| 53 | +) |
| 54 | +select |
| 55 | + coalesce(nullif(schema_name, 'public') || '.', '') || table_name || coalesce(' [' || tblspace || ']', '') as "Table", |
| 56 | + ( |
| 57 | + with ops as ( |
| 58 | + select * from data2 d2 where d2.schema_name is not distinct from data2.schema_name and d2.table_name = data2.table_name |
| 59 | + ), ops_ratios(opname, ratio) as ( |
| 60 | + select |
| 61 | + 'select', |
| 62 | + case when processed_tup_total > 0 then tuples_selected::numeric / processed_tup_total else 0 end |
| 63 | + from ops |
| 64 | + union all |
| 65 | + select |
| 66 | + 'insert', |
| 67 | + case when processed_tup_total > 0 then n_tup_ins::numeric / processed_tup_total else 0 end |
| 68 | + from ops |
| 69 | + union all |
| 70 | + select |
| 71 | + 'delete', |
| 72 | + case when processed_tup_total > 0 then n_tup_del::numeric / processed_tup_total else 0 end |
| 73 | + from ops |
| 74 | + union all |
| 75 | + select |
| 76 | + 'update', |
| 77 | + case when processed_tup_total > 0 then n_tup_upd::numeric / processed_tup_total else 0 end |
| 78 | + from ops |
| 79 | + ) |
| 80 | + select |
| 81 | + case |
| 82 | + when ratio > .7 then upper(opname) || ' ~' || round(100 * ratio, 2)::text || '%' |
| 83 | + else 'Mixed: ' || ( |
| 84 | + select string_agg(upper(left(opname, 1)) || ' ~' || round(100 * ratio, 2)::text || '%', ', ' order by ratio desc) |
| 85 | + from (select * from ops_ratios where ratio > .2) _ |
| 86 | + ) |
| 87 | + end |
| 88 | + from ops_ratios |
| 89 | + order by ratio desc |
| 90 | + limit 1 |
| 91 | + ) as "Load Type", |
| 92 | + processed_tup_total as "Total (S+I+D+U)", |
| 93 | + tuples_selected as "SELECTed", |
| 94 | + n_tup_ins as "INSERTed", |
| 95 | + n_tup_del as "DELETEd", |
| 96 | + n_tup_upd as "UPDATEd", |
| 97 | + round(100 * upd_hot_ratio, 2) as "HOT-updated, %", |
| 98 | + case when seq_tup_read + coalesce(idx_tup_fetch, 0) > 0 then round(100 * seq_tup_read::numeric / (seq_tup_read + coalesce(idx_tup_fetch, 0)), 2) else 0 end as "SeqScan, %" |
| 99 | +from data2 |
| 100 | +order by ord, processed_tup_total desc; |
0 commit comments