use materialized view, simplify resulting table, 1000x speed up

This commit is contained in:
Ryan Voots 2025-05-11 20:41:23 -04:00
parent 762ad55164
commit 52696d1037

View file

@ -1,44 +1,40 @@
SELECT cron.schedule('calculate-a1c', '15 seconds', $$
WITH gtime AS (
SELECT MAX("time") AS time FROM "glucose-processed-full" LIMIT 1
SELECT MAX("time") AS time FROM "glucose-processed-a1c"
),
stime AS (
SELECT MIN("glucose-processed"."time") AS time FROM "glucose-processed" LIMIT 1
stime AS MATERIALIZED (
SELECT MIN("glucose-processed"."time") AS time FROM "glucose-processed"
),
avgs AS (
SELECT "glucose-processed"."time",
"glucose-processed".smoothval,
"glucose-processed".absvalue,
"glucose-processed".delta1st,
"glucose-processed".delta2nd,
ema("glucose-processed".delta1st, 0.25::real) OVER (ORDER BY "glucose-processed"."time") AS smoothdelta1st,
ema("glucose-processed".delta2nd, 0.25::real) OVER (ORDER BY "glucose-processed"."time") AS smoothdelta2nd,
stddev("glucose-processed".delta1st) OVER (ORDER BY "glucose-processed"."time" RANGE BETWEEN '02:00:00'::interval PRECEDING AND CURRENT ROW) AS std_dev_delta1st,
avg("glucose-processed".absvalue) OVER (ORDER BY "glucose-processed"."time" RANGE BETWEEN '3 mons'::interval PRECEDING AND CURRENT ROW) AS "3mo_eabg",
avg("glucose-processed".absvalue) OVER (ORDER BY "glucose-processed"."time" RANGE BETWEEN '7 days'::interval PRECEDING AND CURRENT ROW) AS "7day_eabg"
smoothed AS MATERIALIZED (
SELECT MIN("glucose-processed"."time") as time,
AVG("glucose-processed".absvalue) AS absvalue
FROM "glucose-processed"
LEFT JOIN "stime" ON 1=1
LEFT JOIN "gtime" ON 1=1
WHERE "glucose-processed"."time" >= (COALESCE(gtime.time, stime.time) - '3.1 months'::interval)
ORDER BY "glucose-processed"."time"
LEFT JOIN "stime" ON 1=1
LEFT JOIN "gtime" ON 1=1
WHERE "glucose-processed"."time" >= (COALESCE(gtime.time, stime.time) - '3.1 months'::interval)
GROUP BY date_trunc('hour', "glucose-processed"."time") + date_part('minute', "glucose-processed"."time")::int / 5 * interval '5 min'
ORDER BY 1 ASC
),
avgs AS (
SELECT smoothed.time,
avg(absvalue) OVER (ORDER BY "time" RANGE BETWEEN '3 mons'::interval PRECEDING AND CURRENT ROW) AS "3mo_eabg",
avg(absvalue) OVER (ORDER BY "time" RANGE BETWEEN '7 days'::interval PRECEDING AND CURRENT ROW) AS "7day_eabg"
FROM smoothed
ORDER BY smoothed."time" ASC
)
INSERT INTO "glucose-processed-a1c"
SELECT a."time",
absvalue,
delta1st,
delta2nd,
smoothval,
std_dev_delta1st,
"3mo_eabg",
"7day_eabg",
("3mo_eabg" + 46.7::double precision) / 28.7::double precision AS "3mo_ea1c",
("7day_eabg" + 46.7::double precision) / 28.7::double precision AS "7day_ea1c",
smoothdelta1st,
smoothdelta2nd
("3mo_eabg" + 46.7) / 28.7 AS "3mo_ea1c",
("7day_eabg" + 46.7) / 28.7 AS "7day_ea1c"
FROM avgs AS a
LEFT JOIN "stime" ON 1=1
LEFT JOIN "gtime" ON 1=1
WHERE std_dev_delta1st IS NOT NULL
AND a."time" >= COALESCE(gtime.time, stime.time)
LEFT JOIN "stime" ON 1=1
LEFT JOIN "gtime" ON 1=1
WHERE a."time" >= COALESCE(gtime.time, stime.time)
ORDER BY a."time" ASC
LIMIT 100
$$);
LIMIT 1000
ON CONFLICT ("time") DO NOTHING
$$);