feat(coderd/database): use `template_usage_stats` in `GetUserLatencyInsights` query (#12671)

This PR updates the `GetUserLatencyInsights` query to use rolled up `template_usage_stats` instead of raw agent and app stats.
This commit is contained in:
Mathias Fredriksson 2024-03-25 16:07:40 +02:00 committed by GitHub
parent 5738a03930
commit a8ed689bda
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
3 changed files with 70 additions and 54 deletions

View File

@ -4300,27 +4300,44 @@ func (q *FakeQuerier) GetUserLatencyInsights(_ context.Context, arg database.Get
q.mutex.RLock()
defer q.mutex.RUnlock()
/*
SELECT
tus.user_id,
u.username,
u.avatar_url,
array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids,
COALESCE((PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY tus.median_latency_ms)), -1)::float AS workspace_connection_latency_50,
COALESCE((PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY tus.median_latency_ms)), -1)::float AS workspace_connection_latency_95
FROM
template_usage_stats tus
JOIN
users u
ON
u.id = tus.user_id
WHERE
tus.start_time >= @start_time::timestamptz
AND tus.end_time <= @end_time::timestamptz
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
tus.user_id, u.username, u.avatar_url
ORDER BY
tus.user_id ASC;
*/
latenciesByUserID := make(map[uuid.UUID][]float64)
seenTemplatesByUserID := make(map[uuid.UUID]map[uuid.UUID]struct{})
for _, s := range q.workspaceAgentStats {
if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, s.TemplateID) {
seenTemplatesByUserID := make(map[uuid.UUID][]uuid.UUID)
for _, stat := range q.templateUsageStats {
if stat.StartTime.Before(arg.StartTime) || stat.EndTime.After(arg.EndTime) {
continue
}
if !arg.StartTime.Equal(s.CreatedAt) && (s.CreatedAt.Before(arg.StartTime) || s.CreatedAt.After(arg.EndTime)) {
continue
}
if s.ConnectionCount == 0 {
continue
}
if s.ConnectionMedianLatencyMS <= 0 {
if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, stat.TemplateID) {
continue
}
latenciesByUserID[s.UserID] = append(latenciesByUserID[s.UserID], s.ConnectionMedianLatencyMS)
if seenTemplatesByUserID[s.UserID] == nil {
seenTemplatesByUserID[s.UserID] = make(map[uuid.UUID]struct{})
if stat.MedianLatencyMs.Valid {
latenciesByUserID[stat.UserID] = append(latenciesByUserID[stat.UserID], stat.MedianLatencyMs.Float64)
}
seenTemplatesByUserID[s.UserID][s.TemplateID] = struct{}{}
seenTemplatesByUserID[stat.UserID] = uniqueSortedUUIDs(append(seenTemplatesByUserID[stat.UserID], stat.TemplateID))
}
tryPercentile := func(fs []float64, p float64) float64 {
@ -4333,15 +4350,6 @@ func (q *FakeQuerier) GetUserLatencyInsights(_ context.Context, arg database.Get
var rows []database.GetUserLatencyInsightsRow
for userID, latencies := range latenciesByUserID {
sort.Float64s(latencies)
templateIDSet := seenTemplatesByUserID[userID]
templateIDs := make([]uuid.UUID, 0, len(templateIDSet))
for templateID := range templateIDSet {
templateIDs = append(templateIDs, templateID)
}
slices.SortFunc(templateIDs, func(a, b uuid.UUID) int {
return slice.Ascending(a.String(), b.String())
})
user, err := q.getUserByIDNoLock(userID)
if err != nil {
return nil, err
@ -4350,7 +4358,7 @@ func (q *FakeQuerier) GetUserLatencyInsights(_ context.Context, arg database.Get
UserID: userID,
Username: user.Username,
AvatarURL: user.AvatarURL,
TemplateIDs: templateIDs,
TemplateIDs: seenTemplatesByUserID[userID],
WorkspaceConnectionLatency50: tryPercentile(latencies, 50),
WorkspaceConnectionLatency95: tryPercentile(latencies, 95),
}

View File

@ -2474,22 +2474,26 @@ func (q *sqlQuerier) GetUserActivityInsights(ctx context.Context, arg GetUserAct
const getUserLatencyInsights = `-- name: GetUserLatencyInsights :many
SELECT
workspace_agent_stats.user_id,
users.username,
users.avatar_url,
array_agg(DISTINCT template_id)::uuid[] AS template_ids,
coalesce((PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY connection_median_latency_ms)), -1)::FLOAT AS workspace_connection_latency_50,
coalesce((PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY connection_median_latency_ms)), -1)::FLOAT AS workspace_connection_latency_95
FROM workspace_agent_stats
JOIN users ON (users.id = workspace_agent_stats.user_id)
tus.user_id,
u.username,
u.avatar_url,
array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids,
COALESCE((PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY tus.median_latency_ms)), -1)::float AS workspace_connection_latency_50,
COALESCE((PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY tus.median_latency_ms)), -1)::float AS workspace_connection_latency_95
FROM
template_usage_stats tus
JOIN
users u
ON
u.id = tus.user_id
WHERE
workspace_agent_stats.created_at >= $1
AND workspace_agent_stats.created_at < $2
AND workspace_agent_stats.connection_median_latency_ms > 0
AND workspace_agent_stats.connection_count > 0
AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN template_id = ANY($3::uuid[]) ELSE TRUE END
GROUP BY workspace_agent_stats.user_id, users.username, users.avatar_url
ORDER BY user_id ASC
tus.start_time >= $1::timestamptz
AND tus.end_time <= $2::timestamptz
AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN tus.template_id = ANY($3::uuid[]) ELSE TRUE END
GROUP BY
tus.user_id, u.username, u.avatar_url
ORDER BY
tus.user_id ASC
`
type GetUserLatencyInsightsParams struct {

View File

@ -4,22 +4,26 @@
-- template_ids, meaning only user data from workspaces based on those templates
-- will be included.
SELECT
workspace_agent_stats.user_id,
users.username,
users.avatar_url,
array_agg(DISTINCT template_id)::uuid[] AS template_ids,
coalesce((PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY connection_median_latency_ms)), -1)::FLOAT AS workspace_connection_latency_50,
coalesce((PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY connection_median_latency_ms)), -1)::FLOAT AS workspace_connection_latency_95
FROM workspace_agent_stats
JOIN users ON (users.id = workspace_agent_stats.user_id)
tus.user_id,
u.username,
u.avatar_url,
array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids,
COALESCE((PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY tus.median_latency_ms)), -1)::float AS workspace_connection_latency_50,
COALESCE((PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY tus.median_latency_ms)), -1)::float AS workspace_connection_latency_95
FROM
template_usage_stats tus
JOIN
users u
ON
u.id = tus.user_id
WHERE
workspace_agent_stats.created_at >= @start_time
AND workspace_agent_stats.created_at < @end_time
AND workspace_agent_stats.connection_median_latency_ms > 0
AND workspace_agent_stats.connection_count > 0
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
GROUP BY workspace_agent_stats.user_id, users.username, users.avatar_url
ORDER BY user_id ASC;
tus.start_time >= @start_time::timestamptz
AND tus.end_time <= @end_time::timestamptz
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
tus.user_id, u.username, u.avatar_url
ORDER BY
tus.user_id ASC;
-- name: GetUserActivityInsights :many
-- GetUserActivityInsights returns the ranking with top active users.