fix(coderd/database): improve perf of `GetTemplateInsightsByInterval` (#12773)

Refs #12122
This commit is contained in:
Mathias Fredriksson 2024-03-27 14:10:46 +02:00 committed by GitHub
parent ba1eaceda4
commit 47fd190064
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
2 changed files with 26 additions and 18 deletions

View File

@ -1897,7 +1897,7 @@ WITH
CROSS JOIN CROSS JOIN
generate_series( generate_series(
date_trunc('minute', was.session_started_at), date_trunc('minute', was.session_started_at),
-- Subtract 1 microsecond to avoid creating an extra series. -- Subtract 1 μs to avoid creating an extra series.
date_trunc('minute', was.session_ended_at - '1 microsecond'::interval), date_trunc('minute', was.session_ended_at - '1 microsecond'::interval),
'1 minute'::interval '1 minute'::interval
) AS s(minute_bucket) ) AS s(minute_bucket)
@ -2078,14 +2078,17 @@ WITH
ts AS ( ts AS (
SELECT SELECT
d::timestamptz AS from_, d::timestamptz AS from_,
CASE LEAST(
WHEN (d::timestamptz + ($2::int || ' day')::interval) <= $3::timestamptz (d::timestamptz + ($2::int || ' day')::interval)::timestamptz,
THEN (d::timestamptz + ($2::int || ' day')::interval) $3::timestamptz
ELSE $3::timestamptz )::timestamptz AS to_
END AS to_
FROM FROM
-- Subtract 1 microsecond from end_time to avoid including the next interval in the results. generate_series(
generate_series($4::timestamptz, ($3::timestamptz) - '1 microsecond'::interval, ($2::int || ' day')::interval) AS d $4::timestamptz,
-- Subtract 1 μs to avoid creating an extra series.
($3::timestamptz) - '1 microsecond'::interval,
($2::int || ' day')::interval
) AS d
) )
SELECT SELECT
@ -2099,6 +2102,7 @@ LEFT JOIN
template_usage_stats AS tus template_usage_stats AS tus
ON ON
tus.start_time >= ts.from_ tus.start_time >= ts.from_
AND tus.start_time < ts.to_ -- End time exclusion criteria optimization for index.
AND tus.end_time <= ts.to_ AND tus.end_time <= ts.to_
AND CASE WHEN COALESCE(array_length($1::uuid[], 1), 0) > 0 THEN tus.template_id = ANY($1::uuid[]) ELSE TRUE END AND CASE WHEN COALESCE(array_length($1::uuid[], 1), 0) > 0 THEN tus.template_id = ANY($1::uuid[]) ELSE TRUE END
GROUP BY GROUP BY
@ -2632,7 +2636,7 @@ WITH
CROSS JOIN CROSS JOIN
generate_series( generate_series(
date_trunc('minute', was.session_started_at), date_trunc('minute', was.session_started_at),
-- Subtract 1 microsecond to avoid creating an extra series. -- Subtract 1 μs to avoid creating an extra series.
date_trunc('minute', was.session_ended_at - '1 microsecond'::interval), date_trunc('minute', was.session_ended_at - '1 microsecond'::interval),
'1 minute'::interval '1 minute'::interval
) AS s(minute_bucket) ) AS s(minute_bucket)

View File

@ -355,7 +355,7 @@ WITH
CROSS JOIN CROSS JOIN
generate_series( generate_series(
date_trunc('minute', was.session_started_at), date_trunc('minute', was.session_started_at),
-- Subtract 1 microsecond to avoid creating an extra series. -- Subtract 1 μs to avoid creating an extra series.
date_trunc('minute', was.session_ended_at - '1 microsecond'::interval), date_trunc('minute', was.session_ended_at - '1 microsecond'::interval),
'1 minute'::interval '1 minute'::interval
) AS s(minute_bucket) ) AS s(minute_bucket)
@ -389,14 +389,17 @@ WITH
ts AS ( ts AS (
SELECT SELECT
d::timestamptz AS from_, d::timestamptz AS from_,
CASE LEAST(
WHEN (d::timestamptz + (@interval_days::int || ' day')::interval) <= @end_time::timestamptz (d::timestamptz + (@interval_days::int || ' day')::interval)::timestamptz,
THEN (d::timestamptz + (@interval_days::int || ' day')::interval) @end_time::timestamptz
ELSE @end_time::timestamptz )::timestamptz AS to_
END AS to_
FROM FROM
-- Subtract 1 microsecond from end_time to avoid including the next interval in the results. generate_series(
generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 microsecond'::interval, (@interval_days::int || ' day')::interval) AS d @start_time::timestamptz,
-- Subtract 1 μs to avoid creating an extra series.
(@end_time::timestamptz) - '1 microsecond'::interval,
(@interval_days::int || ' day')::interval
) AS d
) )
SELECT SELECT
@ -410,6 +413,7 @@ LEFT JOIN
template_usage_stats AS tus template_usage_stats AS tus
ON ON
tus.start_time >= ts.from_ tus.start_time >= ts.from_
AND tus.start_time < ts.to_ -- End time exclusion criteria optimization for index.
AND tus.end_time <= ts.to_ AND tus.end_time <= ts.to_
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN tus.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN tus.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
GROUP BY GROUP BY
@ -473,7 +477,7 @@ WITH
CROSS JOIN CROSS JOIN
generate_series( generate_series(
date_trunc('minute', was.session_started_at), date_trunc('minute', was.session_started_at),
-- Subtract 1 microsecond to avoid creating an extra series. -- Subtract 1 μs to avoid creating an extra series.
date_trunc('minute', was.session_ended_at - '1 microsecond'::interval), date_trunc('minute', was.session_ended_at - '1 microsecond'::interval),
'1 minute'::interval '1 minute'::interval
) AS s(minute_bucket) ) AS s(minute_bucket)