mirror of
https://github.com/coder/coder.git
synced 2025-07-03 16:13:58 +00:00
feat: expose insights into user activity (#9807)
This commit is contained in:
@ -2022,6 +2022,127 @@ func (q *sqlQuerier) GetTemplateParameterInsights(ctx context.Context, arg GetTe
|
||||
return items, nil
|
||||
}
|
||||
|
||||
const getUserActivityInsights = `-- name: GetUserActivityInsights :many
|
||||
WITH app_stats AS (
|
||||
SELECT
|
||||
s.start_time,
|
||||
was.user_id,
|
||||
w.template_id,
|
||||
60 as seconds
|
||||
FROM workspace_app_stats was
|
||||
JOIN workspaces w ON (
|
||||
w.id = was.workspace_id
|
||||
AND CASE WHEN COALESCE(array_length($1::uuid[], 1), 0) > 0 THEN w.template_id = ANY($1::uuid[]) ELSE TRUE END
|
||||
)
|
||||
-- This table contains both 1 minute entries and >1 minute entries,
|
||||
-- to calculate this with our uniqueness constraints, we generate series
|
||||
-- for the longer intervals.
|
||||
CROSS JOIN LATERAL generate_series(
|
||||
date_trunc('minute', was.session_started_at),
|
||||
-- Subtract 1 microsecond to avoid creating an extra series.
|
||||
date_trunc('minute', was.session_ended_at - '1 microsecond'::interval),
|
||||
'1 minute'::interval
|
||||
) s(start_time)
|
||||
WHERE
|
||||
s.start_time >= $2::timestamptz
|
||||
-- Subtract one minute because the series only contains the start time.
|
||||
AND s.start_time < ($3::timestamptz) - '1 minute'::interval
|
||||
GROUP BY s.start_time, w.template_id, was.user_id
|
||||
), session_stats AS (
|
||||
SELECT
|
||||
date_trunc('minute', was.created_at) as start_time,
|
||||
was.user_id,
|
||||
was.template_id,
|
||||
CASE WHEN
|
||||
SUM(was.session_count_vscode) > 0 OR
|
||||
SUM(was.session_count_jetbrains) > 0 OR
|
||||
SUM(was.session_count_reconnecting_pty) > 0 OR
|
||||
SUM(was.session_count_ssh) > 0
|
||||
THEN 60 ELSE 0 END as seconds
|
||||
FROM workspace_agent_stats was
|
||||
WHERE
|
||||
was.created_at >= $2::timestamptz
|
||||
AND was.created_at < $3::timestamptz
|
||||
AND was.connection_count > 0
|
||||
AND CASE WHEN COALESCE(array_length($1::uuid[], 1), 0) > 0 THEN was.template_id = ANY($1::uuid[]) ELSE TRUE END
|
||||
GROUP BY date_trunc('minute', was.created_at), was.user_id, was.template_id
|
||||
), combined_stats AS (
|
||||
SELECT
|
||||
user_id,
|
||||
template_id,
|
||||
start_time,
|
||||
seconds
|
||||
FROM app_stats
|
||||
UNION
|
||||
SELECT
|
||||
user_id,
|
||||
template_id,
|
||||
start_time,
|
||||
seconds
|
||||
FROM session_stats
|
||||
)
|
||||
SELECT
|
||||
users.id as user_id,
|
||||
users.username,
|
||||
users.avatar_url,
|
||||
array_agg(DISTINCT template_id)::uuid[] AS template_ids,
|
||||
SUM(seconds) AS usage_seconds
|
||||
FROM combined_stats
|
||||
JOIN users ON (users.id = combined_stats.user_id)
|
||||
GROUP BY users.id, username, avatar_url
|
||||
ORDER BY user_id ASC
|
||||
`
|
||||
|
||||
type GetUserActivityInsightsParams struct {
|
||||
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
|
||||
StartTime time.Time `db:"start_time" json:"start_time"`
|
||||
EndTime time.Time `db:"end_time" json:"end_time"`
|
||||
}
|
||||
|
||||
type GetUserActivityInsightsRow struct {
|
||||
UserID uuid.UUID `db:"user_id" json:"user_id"`
|
||||
Username string `db:"username" json:"username"`
|
||||
AvatarURL sql.NullString `db:"avatar_url" json:"avatar_url"`
|
||||
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
|
||||
UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"`
|
||||
}
|
||||
|
||||
// GetUserActivityInsights returns the ranking with top active users.
|
||||
// The result can be filtered on template_ids, meaning only user data from workspaces
|
||||
// based on those templates will be included.
|
||||
// Note: When selecting data from multiple templates or the entire deployment,
|
||||
// be aware that it may lead to an increase in "usage" numbers (cumulative). In such cases,
|
||||
// users may be counted multiple times for the same time interval if they have used multiple templates
|
||||
// simultaneously.
|
||||
func (q *sqlQuerier) GetUserActivityInsights(ctx context.Context, arg GetUserActivityInsightsParams) ([]GetUserActivityInsightsRow, error) {
|
||||
rows, err := q.db.QueryContext(ctx, getUserActivityInsights, pq.Array(arg.TemplateIDs), arg.StartTime, arg.EndTime)
|
||||
if err != nil {
|
||||
return nil, err
|
||||
}
|
||||
defer rows.Close()
|
||||
var items []GetUserActivityInsightsRow
|
||||
for rows.Next() {
|
||||
var i GetUserActivityInsightsRow
|
||||
if err := rows.Scan(
|
||||
&i.UserID,
|
||||
&i.Username,
|
||||
&i.AvatarURL,
|
||||
pq.Array(&i.TemplateIDs),
|
||||
&i.UsageSeconds,
|
||||
); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
items = append(items, i)
|
||||
}
|
||||
if err := rows.Close(); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
if err := rows.Err(); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
return items, nil
|
||||
}
|
||||
|
||||
const getUserLatencyInsights = `-- name: GetUserLatencyInsights :many
|
||||
SELECT
|
||||
workspace_agent_stats.user_id,
|
||||
|
Reference in New Issue
Block a user