61 lines
2.4 KiB
PL/PgSQL
61 lines
2.4 KiB
PL/PgSQL
CREATE OR REPLACE FUNCTION public.c77_dbh_update_vacuum_stats()
|
|
RETURNS void AS $$
|
|
DECLARE
|
|
v_has_pgstattuple boolean;
|
|
BEGIN
|
|
-- Check if pgstattuple is installed
|
|
SELECT EXISTS (
|
|
SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple'
|
|
) INTO v_has_pgstattuple;
|
|
|
|
-- Insert or update vacuum stats for all user tables
|
|
INSERT INTO public.c77_dbh_vacuum_stats (
|
|
table_name, last_vacuum, last_autovacuum, vacuum_count,
|
|
dead_tuples, live_tuples, table_size, last_updated
|
|
)
|
|
SELECT
|
|
(n.nspname || '.' || c.relname) AS table_name,
|
|
s.last_vacuum,
|
|
s.last_autovacuum,
|
|
COALESCE(s.vacuum_count, 0) + COALESCE(s.autovacuum_count, 0) AS vacuum_count,
|
|
s.n_dead_tup AS dead_tuples,
|
|
s.n_live_tup AS live_tuples,
|
|
pg_relation_size(c.oid) AS table_size,
|
|
now() AS last_updated
|
|
FROM pg_stat_all_tables s
|
|
JOIN pg_class c ON c.oid = s.relid
|
|
JOIN pg_namespace n ON n.oid = c.relnamespace
|
|
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')
|
|
ON CONFLICT (table_name) DO UPDATE
|
|
SET
|
|
last_vacuum = EXCLUDED.last_vacuum,
|
|
last_autovacuum = EXCLUDED.last_autovacuum,
|
|
vacuum_count = EXCLUDED.vacuum_count,
|
|
dead_tuples = EXCLUDED.dead_tuples,
|
|
live_tuples = EXCLUDED.live_tuples,
|
|
table_size = EXCLUDED.table_size,
|
|
last_updated = EXCLUDED.last_updated;
|
|
|
|
-- Update bloat estimate
|
|
IF v_has_pgstattuple THEN
|
|
-- Use pgstattuple for precise bloat if available
|
|
UPDATE public.c77_dbh_vacuum_stats v
|
|
SET bloat_estimate = ROUND(CAST(COALESCE(t.free_percent + t.dead_tuple_percent, 0) AS numeric), 2)
|
|
FROM (
|
|
SELECT (pgstattuple(c.oid)).*
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON n.oid = c.relnamespace
|
|
WHERE (n.nspname || '.' || c.relname) = v.table_name
|
|
) t
|
|
WHERE v.last_updated = now();
|
|
ELSE
|
|
-- Fallback to heuristic bloat estimate
|
|
UPDATE public.c77_dbh_vacuum_stats
|
|
SET bloat_estimate = CASE
|
|
WHEN live_tuples + dead_tuples = 0 THEN 0
|
|
ELSE ROUND((dead_tuples::numeric / (live_tuples + dead_tuples)) * 100, 2)
|
|
END
|
|
WHERE last_updated = now();
|
|
END IF;
|
|
END;
|
|
$$ LANGUAGE plpgsql; |