From 422e86f0a7c87bc670a1f668d948b482057d9593 Mon Sep 17 00:00:00 2001 From: "Peter J. Holzer" Date: Sun, 5 Sep 2021 09:27:13 +0200 Subject: [PATCH] Use lateral joins to improve performance Milliseconds instead of seconds \o/. --- check_df_files | 74 +++++++++++++++++++++++++++++++------------------- check_df_space | 74 +++++++++++++++++++++++++++++++------------------- 2 files changed, 92 insertions(+), 56 deletions(-) diff --git a/check_df_files b/check_df_files index 89ee2f7..43d6c78 100755 --- a/check_df_files +++ b/check_df_files @@ -12,34 +12,52 @@ db = psycopg2.connect('') csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor) csr.execute( - """ - with recursive t as ( - select '2 minutes'::interval as d - union - select d * 2 from t where d < '1 year'::interval - ), - a as ( - select distinct hostname, filesystem, min(ts), max(ts) - from df, t - where ts >= now() - t.d - group by hostname, filesystem, t.d - ), - forecast as ( - select - a.hostname, a.filesystem, - c.ts - b.ts as d, - c.ts + (c.ts - b.ts) as when, - c.f_used + (c.f_used - b.f_used) as used, - (c.f_used + (c.f_used - b.f_used)) / b.f_usable * 100 as percent, - (c.f_used + (c.f_used - b.f_used)) > b.f_usable as capacity_exceeded - from a - join df b on (a.hostname = b.hostname and a.filesystem = b.filesystem and a.min = b.ts) - join df c on (a.hostname = c.hostname and a.filesystem = c.filesystem and a.max = c.ts) - ) - select * from forecast - where capacity_exceeded - order by 1, 2, 3 - """ + """ + with recursive + t as ( + select '2 minutes'::interval as d + union + select d * 2 from t where d < '1 year'::interval + ), + fs as ( + select distinct hostname, filesystem + from df + where ts >= now() - '2 minutes'::interval + group by hostname, filesystem + ), + forecast as ( + select + fs.hostname, fs.filesystem, + new.ts + (new.ts - old.ts) as when, + new.ts + (new.ts - old.ts) - now() as d, + new.f_used + (new.f_used - old.f_used) as used, + (new.f_used + (new.f_used - old.f_used)) / old.f_usable * 100 as percent, + (new.f_used + (new.f_used - old.f_used)) > old.f_usable as capacity_exceeded + from fs, t, + lateral ( + select * + from df + where + df.hostname = fs.hostname + and df.filesystem = fs.filesystem + and df.ts >= now() - t.d + order by ts + limit 1 + ) old, + lateral ( + select * + from df + where + df.hostname = fs.hostname + and df.filesystem = fs.filesystem + order by ts desc + limit 1 + ) new + ) + select * from forecast + where capacity_exceeded + order by "when" + """ ) status = 0 diff --git a/check_df_space b/check_df_space index a82fb84..a21e759 100755 --- a/check_df_space +++ b/check_df_space @@ -12,34 +12,52 @@ db = psycopg2.connect('') csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor) csr.execute( - """ - with recursive t as ( - select '2 minutes'::interval as d - union - select d * 2 from t where d < '1 year'::interval - ), - a as ( - select distinct hostname, filesystem, min(ts), max(ts) - from df, t - where ts >= now() - t.d - group by hostname, filesystem, t.d - ), - forecast as ( - select - a.hostname, a.filesystem, - c.ts - b.ts as d, - c.ts + (c.ts - b.ts) as when, - c.s_used + (c.s_used - b.s_used) as used, - (c.s_used + (c.s_used - b.s_used)) / b.s_usable * 100 as percent, - (c.s_used + (c.s_used - b.s_used)) > b.s_usable as capacity_exceeded - from a - join df b on (a.hostname = b.hostname and a.filesystem = b.filesystem and a.min = b.ts) - join df c on (a.hostname = c.hostname and a.filesystem = c.filesystem and a.max = c.ts) - ) - select * from forecast - where capacity_exceeded - order by 1, 2, 3 - """ + """ + with recursive + t as ( + select '2 minutes'::interval as d + union + select d * 2 from t where d < '1 year'::interval + ), + fs as ( + select distinct hostname, filesystem + from df + where ts >= now() - '2 minutes'::interval + group by hostname, filesystem + ), + forecast as ( + select + fs.hostname, fs.filesystem, + new.ts + (new.ts - old.ts) as when, + new.ts + (new.ts - old.ts) - now() as d, + new.s_used + (new.s_used - old.s_used) as used, + (new.s_used + (new.s_used - old.s_used)) / old.s_usable * 100 as percent, + (new.s_used + (new.s_used - old.s_used)) > old.s_usable as capacity_exceeded + from fs, t, + lateral ( + select * + from df + where + df.hostname = fs.hostname + and df.filesystem = fs.filesystem + and df.ts >= now() - t.d + order by ts + limit 1 + ) old, + lateral ( + select * + from df + where + df.hostname = fs.hostname + and df.filesystem = fs.filesystem + order by ts desc + limit 1 + ) new + ) + select * from forecast + where capacity_exceeded + order by "when" + """ ) status = 0