Use lateral joins to improve performance

Milliseconds instead of seconds \o/.
This commit is contained in:
Peter J. Holzer 2021-09-05 09:27:13 +02:00
parent 2f4096c5af
commit 422e86f0a7
2 changed files with 92 additions and 56 deletions

View File

@ -13,32 +13,50 @@ csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor)
csr.execute(
"""
with recursive t as (
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
fs as (
select distinct hostname, filesystem
from df
where ts >= now() - '2 minutes'::interval
group by hostname, filesystem
),
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)
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 1, 2, 3
order by "when"
"""
)

View File

@ -13,32 +13,50 @@ csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor)
csr.execute(
"""
with recursive t as (
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
fs as (
select distinct hostname, filesystem
from df
where ts >= now() - '2 minutes'::interval
group by hostname, filesystem
),
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)
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 1, 2, 3
order by "when"
"""
)