diff --git a/mv_stats.sql b/mv_stats.sql new file mode 100644 index 0000000..f8a5399 --- /dev/null +++ b/mv_stats.sql @@ -0,0 +1,100 @@ +CREATE TABLE IF NOT EXISTS public.c77_dbh_mv_stats ( + mv_name text COLLATE pg_catalog."default", + create_mv timestamp without time zone, + mod_mv timestamp without time zone, + refresh_mv_last timestamp without time zone, + refresh_count integer DEFAULT 0, + refresh_mv_time_last interval, + refresh_mv_time_total interval DEFAULT '00:00:00'::interval, + refresh_mv_time_min interval, + refresh_mv_time_max interval, + reset_last timestamp without time zone +); +REVOKE ALL ON TABLE public.c77_dbh_mv_stats FROM PUBLIC; +GRANT SELECT ON TABLE public.c77_dbh_mv_stats TO PUBLIC; +GRANT ALL ON TABLE public.c77_dbh_mv_stats TO homestead; + +CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv() + RETURNS event_trigger LANGUAGE plpgsql AS $$ +DECLARE + r RECORD; + flag boolean; + t_refresh_total interval; +BEGIN + FOR r IN SELECT * FROM pg_event_trigger_ddl_commands() LOOP + IF tg_tag = 'CREATE MATERIALIZED VIEW' THEN + INSERT INTO public.c77_dbh_mv_stats (mv_name, create_mv) VALUES (r.object_identity, now()); + END IF; + IF tg_tag = 'ALTER MATERIALIZED VIEW' THEN + SELECT TRUE INTO flag FROM public.c77_dbh_mv_stats WHERE mv_name = r.object_identity; + IF NOT FOUND THEN + INSERT INTO public.c77_dbh_mv_stats (mv_name, create_mv) VALUES (r.object_identity, now()); + DELETE FROM public.c77_dbh_mv_stats WHERE mv_name NOT IN (SELECT schemaname || '.' || matviewname FROM pg_catalog.pg_matviews); + ELSE + UPDATE public.c77_dbh_mv_stats SET mod_mv = now() WHERE mv_name = r.object_identity; + END IF; + END IF; + IF tg_tag = 'REFRESH MATERIALIZED VIEW' THEN + t_refresh_total := clock_timestamp() - (SELECT current_setting('mv_stats.start')::timestamp); + SET mv_stats.start TO DEFAULT; + UPDATE public.c77_dbh_mv_stats + SET refresh_mv_last = now(), + refresh_count = refresh_count + 1, + refresh_mv_time_last = t_refresh_total, + refresh_mv_time_total = refresh_mv_time_total + t_refresh_total, + refresh_mv_time_min = CASE + WHEN refresh_mv_time_min IS NULL THEN t_refresh_total + WHEN refresh_mv_time_min > t_refresh_total THEN t_refresh_total + ELSE refresh_mv_time_min + END, + refresh_mv_time_max = CASE + WHEN refresh_mv_time_max IS NULL THEN t_refresh_total + WHEN refresh_mv_time_max < t_refresh_total THEN t_refresh_total + ELSE refresh_mv_time_max + END + WHERE mv_name = r.object_identity; + END IF; + END LOOP; +END; +$$; + +CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv_drop() + RETURNS event_trigger LANGUAGE plpgsql AS $$ +DECLARE + r RECORD; +BEGIN + FOR r IN SELECT * FROM pg_event_trigger_dropped_objects() LOOP + DELETE FROM public.c77_dbh_mv_stats WHERE mv_name = r.object_identity; + END LOOP; +END; +$$; + +CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv_start() + RETURNS event_trigger LANGUAGE plpgsql AS $$ +BEGIN + PERFORM set_config('mv_stats.start', clock_timestamp()::text, true); +END; +$$; + +CREATE EVENT TRIGGER c77_dbh_trg_mv_info + ON DDL_COMMAND_END + WHEN TAG IN ('CREATE MATERIALIZED VIEW', 'ALTER MATERIALIZED VIEW', 'REFRESH MATERIALIZED VIEW') +EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv(); + +CREATE EVENT TRIGGER c77_dbh_trg_mv_info_drop + ON SQL_DROP + WHEN TAG IN ('DROP MATERIALIZED VIEW') +EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv_drop(); + +CREATE EVENT TRIGGER c77_dbh_trg_mv_info_start + ON DDL_COMMAND_START + WHEN TAG IN ('REFRESH MATERIALIZED VIEW') +EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv_start(); + +CREATE OR REPLACE VIEW public.c77_dbh_matv_stats AS +SELECT mv_name, create_mv, mod_mv, refresh_mv_last, refresh_count, + refresh_mv_time_last, refresh_mv_time_total, refresh_mv_time_min, + refresh_mv_time_max, reset_last +FROM public.c77_dbh_mv_stats; +GRANT SELECT ON TABLE public.c77_dbh_matv_stats TO PUBLIC; +GRANT ALL ON TABLE public.c77_dbh_matv_stats TO homestead;