Use lateral joins to improve performance
Milliseconds instead of seconds \o/.
This commit is contained in:
parent
2f4096c5af
commit
422e86f0a7
|
@ -12,34 +12,52 @@ db = psycopg2.connect('')
|
||||||
csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor)
|
csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor)
|
||||||
|
|
||||||
csr.execute(
|
csr.execute(
|
||||||
"""
|
"""
|
||||||
with recursive t as (
|
with recursive
|
||||||
select '2 minutes'::interval as d
|
t as (
|
||||||
union
|
select '2 minutes'::interval as d
|
||||||
select d * 2 from t where d < '1 year'::interval
|
union
|
||||||
),
|
select d * 2 from t where d < '1 year'::interval
|
||||||
a as (
|
),
|
||||||
select distinct hostname, filesystem, min(ts), max(ts)
|
fs as (
|
||||||
from df, t
|
select distinct hostname, filesystem
|
||||||
where ts >= now() - t.d
|
from df
|
||||||
group by hostname, filesystem, t.d
|
where ts >= now() - '2 minutes'::interval
|
||||||
),
|
group by hostname, filesystem
|
||||||
forecast as (
|
),
|
||||||
select
|
forecast as (
|
||||||
a.hostname, a.filesystem,
|
select
|
||||||
c.ts - b.ts as d,
|
fs.hostname, fs.filesystem,
|
||||||
c.ts + (c.ts - b.ts) as when,
|
new.ts + (new.ts - old.ts) as when,
|
||||||
c.f_used + (c.f_used - b.f_used) as used,
|
new.ts + (new.ts - old.ts) - now() as d,
|
||||||
(c.f_used + (c.f_used - b.f_used)) / b.f_usable * 100 as percent,
|
new.f_used + (new.f_used - old.f_used) as used,
|
||||||
(c.f_used + (c.f_used - b.f_used)) > b.f_usable as capacity_exceeded
|
(new.f_used + (new.f_used - old.f_used)) / old.f_usable * 100 as percent,
|
||||||
from a
|
(new.f_used + (new.f_used - old.f_used)) > old.f_usable as capacity_exceeded
|
||||||
join df b on (a.hostname = b.hostname and a.filesystem = b.filesystem and a.min = b.ts)
|
from fs, t,
|
||||||
join df c on (a.hostname = c.hostname and a.filesystem = c.filesystem and a.max = c.ts)
|
lateral (
|
||||||
)
|
select *
|
||||||
select * from forecast
|
from df
|
||||||
where capacity_exceeded
|
where
|
||||||
order by 1, 2, 3
|
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
|
status = 0
|
||||||
|
|
|
@ -12,34 +12,52 @@ db = psycopg2.connect('')
|
||||||
csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor)
|
csr = db.cursor(cursor_factory=psycopg2.extras.DictCursor)
|
||||||
|
|
||||||
csr.execute(
|
csr.execute(
|
||||||
"""
|
"""
|
||||||
with recursive t as (
|
with recursive
|
||||||
select '2 minutes'::interval as d
|
t as (
|
||||||
union
|
select '2 minutes'::interval as d
|
||||||
select d * 2 from t where d < '1 year'::interval
|
union
|
||||||
),
|
select d * 2 from t where d < '1 year'::interval
|
||||||
a as (
|
),
|
||||||
select distinct hostname, filesystem, min(ts), max(ts)
|
fs as (
|
||||||
from df, t
|
select distinct hostname, filesystem
|
||||||
where ts >= now() - t.d
|
from df
|
||||||
group by hostname, filesystem, t.d
|
where ts >= now() - '2 minutes'::interval
|
||||||
),
|
group by hostname, filesystem
|
||||||
forecast as (
|
),
|
||||||
select
|
forecast as (
|
||||||
a.hostname, a.filesystem,
|
select
|
||||||
c.ts - b.ts as d,
|
fs.hostname, fs.filesystem,
|
||||||
c.ts + (c.ts - b.ts) as when,
|
new.ts + (new.ts - old.ts) as when,
|
||||||
c.s_used + (c.s_used - b.s_used) as used,
|
new.ts + (new.ts - old.ts) - now() as d,
|
||||||
(c.s_used + (c.s_used - b.s_used)) / b.s_usable * 100 as percent,
|
new.s_used + (new.s_used - old.s_used) as used,
|
||||||
(c.s_used + (c.s_used - b.s_used)) > b.s_usable as capacity_exceeded
|
(new.s_used + (new.s_used - old.s_used)) / old.s_usable * 100 as percent,
|
||||||
from a
|
(new.s_used + (new.s_used - old.s_used)) > old.s_usable as capacity_exceeded
|
||||||
join df b on (a.hostname = b.hostname and a.filesystem = b.filesystem and a.min = b.ts)
|
from fs, t,
|
||||||
join df c on (a.hostname = c.hostname and a.filesystem = c.filesystem and a.max = c.ts)
|
lateral (
|
||||||
)
|
select *
|
||||||
select * from forecast
|
from df
|
||||||
where capacity_exceeded
|
where
|
||||||
order by 1, 2, 3
|
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
|
status = 0
|
||||||
|
|
Loading…
Reference in New Issue