Skip to content

Commit

Permalink
[-] fix FREEZE age for partitioned tables in table_stats
Browse files Browse the repository at this point in the history
  • Loading branch information
pashagolub committed May 21, 2024
1 parent fbd867c commit 7752a61
Showing 1 changed file with 155 additions and 3 deletions.
158 changes: 155 additions & 3 deletions src/metrics/metrics.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -3106,7 +3106,7 @@ metrics:
autovacuum_count,
analyze_count,
autoanalyze_count,
age(relfrozenxid) as tx_freeze_age
case when c.relkind != 'p' then age(c.relfrozenxid) else 0 end as tx_freeze_age
from pg_stat_user_tables ut
join
pg_class c on c.oid = ut.relid
Expand Down Expand Up @@ -3239,7 +3239,7 @@ metrics:
autovacuum_count,
analyze_count,
autoanalyze_count,
age(c.relfrozenxid) as tx_freeze_age,
case when c.relkind != 'p' then age(c.relfrozenxid) else 0 end as tx_freeze_age,
extract(epoch from now() - last_seq_scan)::int8 as last_seq_scan_s
from pg_stat_user_tables ut
join pg_class c on c.oid = ut.relid
Expand Down Expand Up @@ -3340,7 +3340,159 @@ metrics:
statement_timeout_seconds: 300
table_stats_approx:
sqls:
11: "with recursive\n q_root_part as (\n select c.oid,\n c.relkind,\n n.nspname root_schema,\n c.relname root_relname\n from pg_class c\n join pg_namespace n on n.oid = c.relnamespace\n where relkind in ('p', 'r')\n and relpersistence != 't'\n and not n.nspname like any (array[E'pg\\\\_%', 'information_schema', E'\\\\_timescaledb%'])\n and not exists(select * from pg_inherits where inhrelid = c.oid)\n and exists(select * from pg_inherits where inhparent = c.oid)\n ),\n q_parts (relid, relkind, level, root) as (\n select oid, relkind, 1, oid\n from q_root_part\n union all\n select inhrelid, c.relkind, level + 1, q.root\n from pg_inherits i\n join q_parts q on inhparent = q.relid\n join pg_class c on c.oid = i.inhrelid\n ),\n q_tstats as (\n with q_tbls_by_total_associated_relpages_approx as (\n select * from (\n select\n c.oid,\n c.relname,\n c.relpages,\n coalesce((select sum(relpages) from pg_class ci join pg_index i on i.indexrelid = ci.oid where i.indrelid = c.oid), 0) as index_relpages,\n coalesce((select coalesce(ct.relpages, 0) + coalesce(cti.relpages, 0) from pg_class ct left join pg_index ti on ti.indrelid = ct.oid left join pg_class cti on cti.oid = ti.indexrelid where ct.oid = c.reltoastrelid), 0) as toast_relpages,\n case when 'autovacuum_enabled=off' = ANY(c.reloptions) then 1 else 0 end as no_autovacuum,\n age(c.relfrozenxid) as tx_freeze_age,\n c.relpersistence \n from\n pg_class c\n join pg_namespace n on n.oid = c.relnamespace\n where\n not n.nspname like any (array[E'pg\\\\_%', 'information_schema', E'\\\\_timescaledb%'])\n and c.relkind = 'r'\n and c.relpersistence != 't'\n ) x\n order by relpages + index_relpages + toast_relpages desc limit 300\n ), q_block_size as (\n select current_setting('block_size')::int8 as bs\n )\n select /* pgwatch3_generated */\n (extract(epoch from now()) * 1e9)::int8 as epoch_ns,\n relid,\n quote_ident(schemaname)||'.'||quote_ident(ut.relname) as tag_table_full_name,\n bs * relpages as table_size_b,\n abs(greatest(ceil(log((bs*relpages+1) / 10^6)), 0))::text as tag_table_size_cardinality_mb, -- i.e. 0=<1MB, 1=<10MB, 2=<100MB,..\n bs * (relpages + index_relpages + toast_relpages) as total_relation_size_b,\n bs * toast_relpages as toast_size_b,\n (extract(epoch from now() - greatest(last_vacuum, last_autovacuum)))::int8 as seconds_since_last_vacuum,\n (extract(epoch from now() - greatest(last_analyze, last_autoanalyze)))::int8 as seconds_since_last_analyze,\n no_autovacuum,\n seq_scan,\n seq_tup_read,\n coalesce(idx_scan, 0) as idx_scan,\n coalesce(idx_tup_fetch, 0) as idx_tup_fetch,\n n_tup_ins,\n n_tup_upd,\n n_tup_del,\n n_tup_hot_upd,\n n_live_tup,\n n_dead_tup,\n vacuum_count,\n autovacuum_count,\n analyze_count,\n autoanalyze_count,\n tx_freeze_age,\n relpersistence \n from\n pg_stat_user_tables ut\n join q_tbls_by_total_associated_relpages_approx t on t.oid = ut.relid\n join q_block_size on true\n where\n -- leaving out fully locked tables as pg_relation_size also wants a lock and would wait\n not exists (select 1 from pg_locks where relation = relid and mode = 'AccessExclusiveLock')\n order by relpages desc\n\n )\n\nselect /* pgwatch3_generated */\n epoch_ns,\n tag_table_full_name,\n 0 as is_part_root,\n table_size_b,\n tag_table_size_cardinality_mb, -- i.e. 0=<1MB, 1=<10MB, 2=<100MB,..\n total_relation_size_b,\n toast_size_b,\n seconds_since_last_vacuum,\n seconds_since_last_analyze,\n no_autovacuum,\n seq_scan,\n seq_tup_read,\n idx_scan,\n idx_tup_fetch,\n n_tup_ins,\n n_tup_upd,\n n_tup_del,\n n_tup_hot_upd,\n n_live_tup,\n n_dead_tup,\n vacuum_count,\n autovacuum_count,\n analyze_count,\n autoanalyze_count,\n tx_freeze_age\nfrom q_tstats\nwhere not exists (select * from q_root_part where oid = q_tstats.relid)\n\nunion all\n\nselect * from (\n select\n epoch_ns,\n quote_ident(qr.root_schema) || '.' || quote_ident(qr.root_relname) as tag_table_full_name,\n 1 as is_part_root,\n sum(table_size_b)::int8 table_size_b,\n abs(greatest(ceil(log((sum(table_size_b) + 1) / 10 ^ 6)),\n 0))::text as tag_table_size_cardinality_mb, -- i.e. 0=<1MB, 1=<10MB, 2=<100MB,..\n sum(total_relation_size_b)::int8 total_relation_size_b,\n sum(toast_size_b)::int8 toast_size_b,\n min(seconds_since_last_vacuum)::int8 seconds_since_last_vacuum,\n min(seconds_since_last_analyze)::int8 seconds_since_last_analyze,\n sum(no_autovacuum)::int8 no_autovacuum,\n sum(seq_scan)::int8 seq_scan,\n sum(seq_tup_read)::int8 seq_tup_read,\n sum(idx_scan)::int8 idx_scan,\n sum(idx_tup_fetch)::int8 idx_tup_fetch,\n sum(n_tup_ins)::int8 n_tup_ins,\n sum(n_tup_upd)::int8 n_tup_upd,\n sum(n_tup_del)::int8 n_tup_del,\n sum(n_tup_hot_upd)::int8 n_tup_hot_upd,\n sum(n_live_tup)::int8 n_live_tup,\n sum(n_dead_tup)::int8 n_dead_tup,\n sum(vacuum_count)::int8 vacuum_count,\n sum(autovacuum_count)::int8 autovacuum_count,\n sum(analyze_count)::int8 analyze_count,\n sum(autoanalyze_count)::int8 autoanalyze_count,\n max(tx_freeze_age)::int8 tx_freeze_age\n from\n q_tstats ts\n join q_parts qp on qp.relid = ts.relid\n join q_root_part qr on qr.oid = qp.root\n group by\n 1, 2\n) x"
11: |-
with recursive /* pgwatch3_generated */
q_root_part as (
select c.oid,
c.relkind,
n.nspname root_schema,
c.relname root_relname
from pg_class c
join pg_namespace n on n.oid = c.relnamespace
where relkind in ('p', 'r')
and relpersistence != 't'
and not n.nspname like any (array[E'pg\\_%', 'information_schema', E'\\_timescaledb%'])
and not exists(select * from pg_inherits where inhrelid = c.oid)
and exists(select * from pg_inherits where inhparent = c.oid)
),
q_parts (relid, relkind, level, root) as (
select oid, relkind, 1, oid
from q_root_part
union all
select inhrelid, c.relkind, level + 1, q.root
from pg_inherits i
join q_parts q on inhparent = q.relid
join pg_class c on c.oid = i.inhrelid
),
q_tstats as (
with q_tbls_by_total_associated_relpages_approx as (
select * from (
select
c.oid,
c.relname,
c.relpages,
coalesce((select sum(relpages) from pg_class ci join pg_index i on i.indexrelid = ci.oid where i.indrelid = c.oid), 0) as index_relpages,
coalesce((select coalesce(ct.relpages, 0) + coalesce(cti.relpages, 0) from pg_class ct left join pg_index ti on ti.indrelid = ct.oid left join pg_class cti on cti.oid = ti.indexrelid where ct.oid = c.reltoastrelid), 0) as toast_relpages,
case when 'autovacuum_enabled=off' = ANY(c.reloptions) then 1 else 0 end as no_autovacuum,
case when c.relkind != 'p' then age(c.relfrozenxid) else 0 end as tx_freeze_age,
c.relpersistence
from
pg_class c
join pg_namespace n on n.oid = c.relnamespace
where
not n.nspname like any (array[E'pg\\_%', 'information_schema', E'\\_timescaledb%'])
and c.relkind = 'r'
and c.relpersistence != 't'
) x
order by relpages + index_relpages + toast_relpages desc limit 300
), q_block_size as (
select current_setting('block_size')::int8 as bs
)
select /* pgwatch2_generated */
(extract(epoch from now()) * 1e9)::int8 as epoch_ns,
relid,
quote_ident(schemaname)||'.'||quote_ident(ut.relname) as tag_table_full_name,
bs * relpages as table_size_b,
abs(greatest(ceil(log((bs*relpages+1) / 10^6)), 0))::text as tag_table_size_cardinality_mb, -- i.e. 0=<1MB, 1=<10MB, 2=<100MB,..
bs * (relpages + index_relpages + toast_relpages) as total_relation_size_b,
bs * toast_relpages as toast_size_b,
(extract(epoch from now() - greatest(last_vacuum, last_autovacuum)))::int8 as seconds_since_last_vacuum,
(extract(epoch from now() - greatest(last_analyze, last_autoanalyze)))::int8 as seconds_since_last_analyze,
no_autovacuum,
seq_scan,
seq_tup_read,
coalesce(idx_scan, 0) as idx_scan,
coalesce(idx_tup_fetch, 0) as idx_tup_fetch,
n_tup_ins,
n_tup_upd,
n_tup_del,
n_tup_hot_upd,
n_live_tup,
n_dead_tup,
vacuum_count,
autovacuum_count,
analyze_count,
autoanalyze_count,
tx_freeze_age,
relpersistence
from
pg_stat_user_tables ut
join q_tbls_by_total_associated_relpages_approx t on t.oid = ut.relid
join q_block_size on true
where
-- leaving out fully locked tables as pg_relation_size also wants a lock and would wait
not exists (select 1 from pg_locks where relation = relid and mode = 'AccessExclusiveLock')
order by relpages desc
)
select /* pgwatch2_generated */
epoch_ns,
tag_table_full_name,
0 as is_part_root,
table_size_b,
tag_table_size_cardinality_mb, -- i.e. 0=<1MB, 1=<10MB, 2=<100MB,..
total_relation_size_b,
toast_size_b,
seconds_since_last_vacuum,
seconds_since_last_analyze,
no_autovacuum,
seq_scan,
seq_tup_read,
idx_scan,
idx_tup_fetch,
n_tup_ins,
n_tup_upd,
n_tup_del,
n_tup_hot_upd,
n_live_tup,
n_dead_tup,
vacuum_count,
autovacuum_count,
analyze_count,
autoanalyze_count,
tx_freeze_age
from q_tstats
where not exists (select * from q_root_part where oid = q_tstats.relid)

union all

select * from (
select
epoch_ns,
quote_ident(qr.root_schema) || '.' || quote_ident(qr.root_relname) as tag_table_full_name,
1 as is_part_root,
sum(table_size_b)::int8 table_size_b,
abs(greatest(ceil(log((sum(table_size_b) + 1) / 10 ^ 6)),
0))::text as tag_table_size_cardinality_mb, -- i.e. 0=<1MB, 1=<10MB, 2=<100MB,..
sum(total_relation_size_b)::int8 total_relation_size_b,
sum(toast_size_b)::int8 toast_size_b,
min(seconds_since_last_vacuum)::int8 seconds_since_last_vacuum,
min(seconds_since_last_analyze)::int8 seconds_since_last_analyze,
sum(no_autovacuum)::int8 no_autovacuum,
sum(seq_scan)::int8 seq_scan,
sum(seq_tup_read)::int8 seq_tup_read,
sum(idx_scan)::int8 idx_scan,
sum(idx_tup_fetch)::int8 idx_tup_fetch,
sum(n_tup_ins)::int8 n_tup_ins,
sum(n_tup_upd)::int8 n_tup_upd,
sum(n_tup_del)::int8 n_tup_del,
sum(n_tup_hot_upd)::int8 n_tup_hot_upd,
sum(n_live_tup)::int8 n_live_tup,
sum(n_dead_tup)::int8 n_dead_tup,
sum(vacuum_count)::int8 vacuum_count,
sum(autovacuum_count)::int8 autovacuum_count,
sum(analyze_count)::int8 analyze_count,
sum(autoanalyze_count)::int8 autoanalyze_count,
max(tx_freeze_age)::int8 tx_freeze_age
from
q_tstats ts
join q_parts qp on qp.relid = ts.relid
join q_root_part qr on qr.oid = qp.root
group by
1, 2
) x;

gauges:
- table_size_b
- total_relation_size_b
Expand Down

0 comments on commit 7752a61

Please sign in to comment.