fix(coderd): fix template insight intervals (#8662)

This commit is contained in:
Mathias Fredriksson
2023-07-21 23:51:35 +03:00
committed by GitHub
parent 65583eca47
commit e0c1aacac1
4 changed files with 33 additions and 14 deletions

View File

@ -24,7 +24,8 @@ ORDER BY user_id ASC;
-- GetTemplateInsights has a granularity of 5 minutes where if a session/app was
-- in use, we will add 5 minutes to the total usage for that session (per user).
WITH d AS (
SELECT generate_series(@start_time::timestamptz, @end_time::timestamptz, '5 minute'::interval) AS d
-- Subtract 1 second from end_time to avoid including the next interval in the results.
SELECT generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 second'::interval, '5 minute'::interval) AS d
), ts AS (
SELECT
d::timestamptz AS from_,
@ -71,7 +72,8 @@ FROM usage_by_user;
-- interval/template, it will be included in the results with 0 active users.
WITH d AS (
-- sqlc workaround, use SELECT generate_series instead of SELECT * FROM generate_series.
SELECT generate_series(@start_time::timestamptz, @end_time::timestamptz, '1 day'::interval) AS d
-- Subtract 1 second from end_time to avoid including the next interval in the results.
SELECT generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 second'::interval, '1 day'::interval) AS d
), ts AS (
SELECT
d::timestamptz AS from_,
@ -91,15 +93,18 @@ WITH d AS (
)
GROUP BY ts.from_, ts.to_, was.user_id
), template_ids AS (
SELECT array_agg(DISTINCT template_id) AS ids
SELECT
from_,
array_agg(DISTINCT template_id) AS ids
FROM usage_by_day, unnest(template_ids) template_id
WHERE template_id IS NOT NULL
GROUP BY from_, template_ids
)
SELECT
from_ AS start_time,
to_ AS end_time,
COALESCE((SELECT ids FROM template_ids), '{}')::uuid[] AS template_ids,
COALESCE((SELECT template_ids.ids FROM template_ids WHERE template_ids.from_ = usage_by_day.from_), '{}')::uuid[] AS template_ids,
COUNT(DISTINCT user_id) AS active_users
FROM usage_by_day, unnest(template_ids) as template_id
FROM usage_by_day
GROUP BY from_, to_;