mirror of
https://github.com/coder/coder.git
synced 2025-07-03 16:13:58 +00:00
feat(coderd): add times_used
to coder_app
s in insights API (#13292)
For now, only applied to `coder_app`s, same logic can be implemented for VS Code, SSH, etc. Part of #13099
This commit is contained in:
committed by
GitHub
parent
63e06853eb
commit
a0fce363cd
@ -1805,7 +1805,7 @@ WITH
|
||||
apps.slug,
|
||||
apps.display_name,
|
||||
apps.icon,
|
||||
tus.app_usage_mins
|
||||
(tus.app_usage_mins -> apps.slug)::smallint AS usage_mins
|
||||
FROM
|
||||
apps
|
||||
JOIN
|
||||
@ -1829,14 +1829,36 @@ WITH
|
||||
display_name,
|
||||
icon,
|
||||
-- See motivation in GetTemplateInsights for LEAST(SUM(n), 30).
|
||||
LEAST(SUM(app_usage.value::smallint), 30) AS usage_mins
|
||||
LEAST(SUM(usage_mins), 30) AS usage_mins
|
||||
FROM
|
||||
template_usage_stats_with_apps, jsonb_each(app_usage_mins) AS app_usage
|
||||
WHERE
|
||||
app_usage.key = slug
|
||||
template_usage_stats_with_apps
|
||||
GROUP BY
|
||||
start_time, user_id, slug, display_name, icon
|
||||
),
|
||||
-- Analyze the users unique app usage across all templates. Count
|
||||
-- usage across consecutive intervals as continuous usage.
|
||||
times_used AS (
|
||||
SELECT DISTINCT ON (user_id, slug, display_name, icon, uniq)
|
||||
slug,
|
||||
display_name,
|
||||
icon,
|
||||
-- Turn start_time into a unique identifier that identifies a users
|
||||
-- continuous app usage. The value of uniq is otherwise garbage.
|
||||
--
|
||||
-- Since we're aggregating per user app usage across templates,
|
||||
-- there can be duplicate start_times. To handle this, we use the
|
||||
-- dense_rank() function, otherwise row_number() would suffice.
|
||||
start_time - (
|
||||
dense_rank() OVER (
|
||||
PARTITION BY
|
||||
user_id, slug, display_name, icon
|
||||
ORDER BY
|
||||
start_time
|
||||
) * '30 minutes'::interval
|
||||
) AS uniq
|
||||
FROM
|
||||
template_usage_stats_with_apps
|
||||
),
|
||||
-- Even though we allow identical apps to be aggregated across
|
||||
-- templates, we still want to be able to report which templates
|
||||
-- the data comes from.
|
||||
@ -1858,7 +1880,17 @@ SELECT
|
||||
ai.slug,
|
||||
ai.display_name,
|
||||
ai.icon,
|
||||
(SUM(ai.usage_mins) * 60)::bigint AS usage_seconds
|
||||
(SUM(ai.usage_mins) * 60)::bigint AS usage_seconds,
|
||||
COALESCE((
|
||||
SELECT
|
||||
COUNT(*)
|
||||
FROM
|
||||
times_used
|
||||
WHERE
|
||||
times_used.slug = ai.slug
|
||||
AND times_used.display_name = ai.display_name
|
||||
AND times_used.icon = ai.icon
|
||||
), 0)::bigint AS times_used
|
||||
FROM
|
||||
app_insights AS ai
|
||||
JOIN
|
||||
@ -1884,6 +1916,7 @@ type GetTemplateAppInsightsRow struct {
|
||||
DisplayName string `db:"display_name" json:"display_name"`
|
||||
Icon string `db:"icon" json:"icon"`
|
||||
UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"`
|
||||
TimesUsed int64 `db:"times_used" json:"times_used"`
|
||||
}
|
||||
|
||||
// GetTemplateAppInsights returns the aggregate usage of each app in a given
|
||||
@ -1905,6 +1938,7 @@ func (q *sqlQuerier) GetTemplateAppInsights(ctx context.Context, arg GetTemplate
|
||||
&i.DisplayName,
|
||||
&i.Icon,
|
||||
&i.UsageSeconds,
|
||||
&i.TimesUsed,
|
||||
); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
|
Reference in New Issue
Block a user