mirror of
https://github.com/coder/coder.git
synced 2025-07-15 22:20:27 +00:00
feat(coderd/database): use template_usage_stats
in GetTemplateAppInsights
query (#12669)
This PR updates the `GetTemplateAppInsights` query to use rolled up `template_usage_stats` instead of raw agent and app stats.
This commit is contained in:
committed by
GitHub
parent
5f3be62c83
commit
5738a03930
@ -799,6 +799,91 @@ func least[T constraints.Ordered](a, b T) T {
|
|||||||
return b
|
return b
|
||||||
}
|
}
|
||||||
|
|
||||||
|
func (q *FakeQuerier) getLatestWorkspaceAppByTemplateIDUserIDSlugNoLock(ctx context.Context, templateID, userID uuid.UUID, slug string) (database.WorkspaceApp, error) {
|
||||||
|
/*
|
||||||
|
SELECT
|
||||||
|
app.display_name,
|
||||||
|
app.icon,
|
||||||
|
app.slug
|
||||||
|
FROM
|
||||||
|
workspace_apps AS app
|
||||||
|
JOIN
|
||||||
|
workspace_agents AS agent
|
||||||
|
ON
|
||||||
|
agent.id = app.agent_id
|
||||||
|
JOIN
|
||||||
|
workspace_resources AS resource
|
||||||
|
ON
|
||||||
|
resource.id = agent.resource_id
|
||||||
|
JOIN
|
||||||
|
workspace_builds AS build
|
||||||
|
ON
|
||||||
|
build.job_id = resource.job_id
|
||||||
|
JOIN
|
||||||
|
workspaces AS workspace
|
||||||
|
ON
|
||||||
|
workspace.id = build.workspace_id
|
||||||
|
WHERE
|
||||||
|
-- Requires lateral join.
|
||||||
|
app.slug = app_usage.key
|
||||||
|
AND workspace.owner_id = tus.user_id
|
||||||
|
AND workspace.template_id = tus.template_id
|
||||||
|
ORDER BY
|
||||||
|
app.created_at DESC
|
||||||
|
LIMIT 1
|
||||||
|
*/
|
||||||
|
|
||||||
|
var workspaces []database.Workspace
|
||||||
|
for _, w := range q.workspaces {
|
||||||
|
if w.TemplateID != templateID || w.OwnerID != userID {
|
||||||
|
continue
|
||||||
|
}
|
||||||
|
workspaces = append(workspaces, w)
|
||||||
|
}
|
||||||
|
slices.SortFunc(workspaces, func(a, b database.Workspace) int {
|
||||||
|
if a.CreatedAt.Before(b.CreatedAt) {
|
||||||
|
return 1
|
||||||
|
} else if a.CreatedAt.Equal(b.CreatedAt) {
|
||||||
|
return 0
|
||||||
|
}
|
||||||
|
return -1
|
||||||
|
})
|
||||||
|
|
||||||
|
for _, workspace := range workspaces {
|
||||||
|
build, err := q.getLatestWorkspaceBuildByWorkspaceIDNoLock(ctx, workspace.ID)
|
||||||
|
if err != nil {
|
||||||
|
continue
|
||||||
|
}
|
||||||
|
|
||||||
|
resources, err := q.getWorkspaceResourcesByJobIDNoLock(ctx, build.JobID)
|
||||||
|
if err != nil {
|
||||||
|
continue
|
||||||
|
}
|
||||||
|
var resourceIDs []uuid.UUID
|
||||||
|
for _, resource := range resources {
|
||||||
|
resourceIDs = append(resourceIDs, resource.ID)
|
||||||
|
}
|
||||||
|
|
||||||
|
agents, err := q.getWorkspaceAgentsByResourceIDsNoLock(ctx, resourceIDs)
|
||||||
|
if err != nil {
|
||||||
|
continue
|
||||||
|
}
|
||||||
|
|
||||||
|
for _, agent := range agents {
|
||||||
|
app, err := q.getWorkspaceAppByAgentIDAndSlugNoLock(ctx, database.GetWorkspaceAppByAgentIDAndSlugParams{
|
||||||
|
AgentID: agent.ID,
|
||||||
|
Slug: slug,
|
||||||
|
})
|
||||||
|
if err != nil {
|
||||||
|
continue
|
||||||
|
}
|
||||||
|
return app, nil
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
return database.WorkspaceApp{}, sql.ErrNoRows
|
||||||
|
}
|
||||||
|
|
||||||
func (*FakeQuerier) AcquireLock(_ context.Context, _ int64) error {
|
func (*FakeQuerier) AcquireLock(_ context.Context, _ int64) error {
|
||||||
return xerrors.New("AcquireLock must only be called within a transaction")
|
return xerrors.New("AcquireLock must only be called within a transaction")
|
||||||
}
|
}
|
||||||
@ -2896,119 +2981,216 @@ func (q *FakeQuerier) GetTemplateAppInsights(ctx context.Context, arg database.G
|
|||||||
q.mutex.RLock()
|
q.mutex.RLock()
|
||||||
defer q.mutex.RUnlock()
|
defer q.mutex.RUnlock()
|
||||||
|
|
||||||
type appKey struct {
|
/*
|
||||||
AccessMethod string
|
WITH
|
||||||
SlugOrPort string
|
*/
|
||||||
Slug string
|
|
||||||
DisplayName string
|
|
||||||
Icon string
|
|
||||||
}
|
|
||||||
type uniqueKey struct {
|
|
||||||
TemplateID uuid.UUID
|
|
||||||
UserID uuid.UUID
|
|
||||||
AgentID uuid.UUID
|
|
||||||
AppKey appKey
|
|
||||||
}
|
|
||||||
|
|
||||||
appUsageIntervalsByUserAgentApp := make(map[uniqueKey]map[time.Time]int64)
|
/*
|
||||||
for _, s := range q.workspaceAppStats {
|
app_insights AS (
|
||||||
// (was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
|
SELECT
|
||||||
// OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
|
tus.user_id,
|
||||||
// OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
|
array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids,
|
||||||
if !(((s.SessionStartedAt.After(arg.StartTime) || s.SessionStartedAt.Equal(arg.StartTime)) && s.SessionStartedAt.Before(arg.EndTime)) ||
|
app_usage.key::text AS app_name,
|
||||||
(s.SessionEndedAt.After(arg.StartTime) && s.SessionEndedAt.Before(arg.EndTime)) ||
|
COALESCE(wa.display_name, '') AS display_name,
|
||||||
(s.SessionStartedAt.Before(arg.StartTime) && (s.SessionEndedAt.After(arg.EndTime) || s.SessionEndedAt.Equal(arg.EndTime)))) {
|
COALESCE(wa.icon, '') AS icon,
|
||||||
|
(wa.slug IS NOT NULL)::boolean AS is_app,
|
||||||
|
LEAST(SUM(app_usage.value::int), 30) AS app_usage_mins
|
||||||
|
FROM
|
||||||
|
template_usage_stats AS tus, jsonb_each(app_usage_mins) AS app_usage
|
||||||
|
LEFT JOIN LATERAL (
|
||||||
|
-- Fetch the latest app info for each app based on slug and template.
|
||||||
|
SELECT
|
||||||
|
app.display_name,
|
||||||
|
app.icon,
|
||||||
|
app.slug
|
||||||
|
FROM
|
||||||
|
workspace_apps AS app
|
||||||
|
JOIN
|
||||||
|
workspace_agents AS agent
|
||||||
|
ON
|
||||||
|
agent.id = app.agent_id
|
||||||
|
JOIN
|
||||||
|
workspace_resources AS resource
|
||||||
|
ON
|
||||||
|
resource.id = agent.resource_id
|
||||||
|
JOIN
|
||||||
|
workspace_builds AS build
|
||||||
|
ON
|
||||||
|
build.job_id = resource.job_id
|
||||||
|
JOIN
|
||||||
|
workspaces AS workspace
|
||||||
|
ON
|
||||||
|
workspace.id = build.workspace_id
|
||||||
|
WHERE
|
||||||
|
-- Requires lateral join.
|
||||||
|
app.slug = app_usage.key
|
||||||
|
AND workspace.owner_id = tus.user_id
|
||||||
|
AND workspace.template_id = tus.template_id
|
||||||
|
ORDER BY
|
||||||
|
app.created_at DESC
|
||||||
|
LIMIT 1
|
||||||
|
) AS wa
|
||||||
|
ON
|
||||||
|
true
|
||||||
|
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.start_time, tus.user_id, app_usage.key::text, wa.display_name, wa.icon, wa.slug
|
||||||
|
),
|
||||||
|
*/
|
||||||
|
|
||||||
|
type appInsightsGroupBy struct {
|
||||||
|
StartTime time.Time
|
||||||
|
UserID uuid.UUID
|
||||||
|
AppName string
|
||||||
|
DisplayName string
|
||||||
|
Icon string
|
||||||
|
IsApp bool
|
||||||
|
}
|
||||||
|
type appInsightsRow struct {
|
||||||
|
appInsightsGroupBy
|
||||||
|
TemplateIDs []uuid.UUID
|
||||||
|
AppUsageMins int64
|
||||||
|
}
|
||||||
|
appInsightRows := make(map[appInsightsGroupBy]appInsightsRow)
|
||||||
|
// FROM
|
||||||
|
for _, stat := range q.templateUsageStats {
|
||||||
|
// WHERE
|
||||||
|
if stat.StartTime.Before(arg.StartTime) || stat.EndTime.After(arg.EndTime) {
|
||||||
|
continue
|
||||||
|
}
|
||||||
|
if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, stat.TemplateID) {
|
||||||
continue
|
continue
|
||||||
}
|
}
|
||||||
|
|
||||||
w, err := q.getWorkspaceByIDNoLock(ctx, s.WorkspaceID)
|
// json_each
|
||||||
if err != nil {
|
for appName, appUsage := range stat.AppUsageMins {
|
||||||
return nil, err
|
// LEFT JOIN LATERAL
|
||||||
}
|
app, _ := q.getLatestWorkspaceAppByTemplateIDUserIDSlugNoLock(ctx, stat.TemplateID, stat.UserID, appName)
|
||||||
|
|
||||||
if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, w.TemplateID) {
|
// SELECT
|
||||||
continue
|
key := appInsightsGroupBy{
|
||||||
}
|
StartTime: stat.StartTime,
|
||||||
|
UserID: stat.UserID,
|
||||||
app, _ := q.getWorkspaceAppByAgentIDAndSlugNoLock(ctx, database.GetWorkspaceAppByAgentIDAndSlugParams{
|
AppName: appName,
|
||||||
AgentID: s.AgentID,
|
DisplayName: app.DisplayName,
|
||||||
Slug: s.SlugOrPort,
|
Icon: app.Icon,
|
||||||
})
|
IsApp: app.Slug != "",
|
||||||
|
}
|
||||||
key := uniqueKey{
|
row, ok := appInsightRows[key]
|
||||||
TemplateID: w.TemplateID,
|
if !ok {
|
||||||
UserID: s.UserID,
|
row = appInsightsRow{
|
||||||
AgentID: s.AgentID,
|
appInsightsGroupBy: key,
|
||||||
AppKey: appKey{
|
}
|
||||||
AccessMethod: s.AccessMethod,
|
}
|
||||||
SlugOrPort: s.SlugOrPort,
|
row.TemplateIDs = append(row.TemplateIDs, stat.TemplateID)
|
||||||
Slug: app.Slug,
|
row.AppUsageMins = least(row.AppUsageMins+appUsage, 30)
|
||||||
DisplayName: app.DisplayName,
|
appInsightRows[key] = row
|
||||||
Icon: app.Icon,
|
|
||||||
},
|
|
||||||
}
|
|
||||||
if appUsageIntervalsByUserAgentApp[key] == nil {
|
|
||||||
appUsageIntervalsByUserAgentApp[key] = make(map[time.Time]int64)
|
|
||||||
}
|
|
||||||
|
|
||||||
t := s.SessionStartedAt.Truncate(5 * time.Minute)
|
|
||||||
if t.Before(arg.StartTime) {
|
|
||||||
t = arg.StartTime
|
|
||||||
}
|
|
||||||
for t.Before(s.SessionEndedAt) && t.Before(arg.EndTime) {
|
|
||||||
appUsageIntervalsByUserAgentApp[key][t] = 60 // 1 minute.
|
|
||||||
t = t.Add(1 * time.Minute)
|
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
appUsageTemplateIDs := make(map[appKey]map[uuid.UUID]struct{})
|
/*
|
||||||
appUsageUserIDs := make(map[appKey]map[uuid.UUID]struct{})
|
templates AS (
|
||||||
appUsage := make(map[appKey]int64)
|
SELECT
|
||||||
for uniqueKey, usage := range appUsageIntervalsByUserAgentApp {
|
app_name,
|
||||||
for _, seconds := range usage {
|
display_name,
|
||||||
if appUsageTemplateIDs[uniqueKey.AppKey] == nil {
|
icon,
|
||||||
appUsageTemplateIDs[uniqueKey.AppKey] = make(map[uuid.UUID]struct{})
|
is_app,
|
||||||
}
|
array_agg(DISTINCT template_id)::uuid[] AS template_ids
|
||||||
appUsageTemplateIDs[uniqueKey.AppKey][uniqueKey.TemplateID] = struct{}{}
|
FROM
|
||||||
if appUsageUserIDs[uniqueKey.AppKey] == nil {
|
app_insights, unnest(template_ids) AS template_id
|
||||||
appUsageUserIDs[uniqueKey.AppKey] = make(map[uuid.UUID]struct{})
|
GROUP BY
|
||||||
}
|
app_name, display_name, icon, is_app
|
||||||
appUsageUserIDs[uniqueKey.AppKey][uniqueKey.UserID] = struct{}{}
|
)
|
||||||
appUsage[uniqueKey.AppKey] += seconds
|
*/
|
||||||
|
|
||||||
|
type appGroupBy struct {
|
||||||
|
AppName string
|
||||||
|
DisplayName string
|
||||||
|
Icon string
|
||||||
|
IsApp bool
|
||||||
|
}
|
||||||
|
type templateRow struct {
|
||||||
|
appGroupBy
|
||||||
|
TemplateIDs []uuid.UUID
|
||||||
|
}
|
||||||
|
|
||||||
|
templateRows := make(map[appGroupBy]templateRow)
|
||||||
|
for _, aiRow := range appInsightRows {
|
||||||
|
key := appGroupBy{
|
||||||
|
AppName: aiRow.AppName,
|
||||||
|
DisplayName: aiRow.DisplayName,
|
||||||
|
Icon: aiRow.Icon,
|
||||||
|
IsApp: aiRow.IsApp,
|
||||||
}
|
}
|
||||||
|
row, ok := templateRows[key]
|
||||||
|
if !ok {
|
||||||
|
row = templateRow{
|
||||||
|
appGroupBy: key,
|
||||||
|
}
|
||||||
|
}
|
||||||
|
row.TemplateIDs = uniqueSortedUUIDs(append(row.TemplateIDs, aiRow.TemplateIDs...))
|
||||||
|
templateRows[key] = row
|
||||||
|
}
|
||||||
|
|
||||||
|
/*
|
||||||
|
SELECT
|
||||||
|
t.template_ids,
|
||||||
|
array_agg(DISTINCT ai.user_id)::uuid[] AS active_user_ids,
|
||||||
|
ai.app_name AS slug_or_port,
|
||||||
|
ai.display_name,
|
||||||
|
ai.icon,
|
||||||
|
ai.is_app,
|
||||||
|
(SUM(ai.app_usage_mins) * 60)::bigint AS usage_seconds
|
||||||
|
FROM
|
||||||
|
app_insights AS ai
|
||||||
|
JOIN
|
||||||
|
templates AS t
|
||||||
|
ON
|
||||||
|
ai.app_name = t.app_name
|
||||||
|
AND ai.display_name = t.display_name
|
||||||
|
AND ai.icon = t.icon
|
||||||
|
AND ai.is_app = t.is_app
|
||||||
|
GROUP BY
|
||||||
|
t.template_ids, ai.app_name, ai.display_name, ai.icon, ai.is_app;
|
||||||
|
*/
|
||||||
|
|
||||||
|
type templateAppInsightsRow struct {
|
||||||
|
TemplateIDs []uuid.UUID
|
||||||
|
ActiveUserIDs []uuid.UUID
|
||||||
|
UsageSeconds int64
|
||||||
|
}
|
||||||
|
groupedRows := make(map[appGroupBy]templateAppInsightsRow)
|
||||||
|
for _, aiRow := range appInsightRows {
|
||||||
|
key := appGroupBy{
|
||||||
|
AppName: aiRow.AppName,
|
||||||
|
DisplayName: aiRow.DisplayName,
|
||||||
|
Icon: aiRow.Icon,
|
||||||
|
IsApp: aiRow.IsApp,
|
||||||
|
}
|
||||||
|
row := groupedRows[key]
|
||||||
|
row.ActiveUserIDs = append(row.ActiveUserIDs, aiRow.UserID)
|
||||||
|
row.UsageSeconds += aiRow.AppUsageMins * 60
|
||||||
|
groupedRows[key] = row
|
||||||
}
|
}
|
||||||
|
|
||||||
var rows []database.GetTemplateAppInsightsRow
|
var rows []database.GetTemplateAppInsightsRow
|
||||||
for appKey, usage := range appUsage {
|
for key, gr := range groupedRows {
|
||||||
templateIDs := make([]uuid.UUID, 0, len(appUsageTemplateIDs[appKey]))
|
|
||||||
for templateID := range appUsageTemplateIDs[appKey] {
|
|
||||||
templateIDs = append(templateIDs, templateID)
|
|
||||||
}
|
|
||||||
slices.SortFunc(templateIDs, func(a, b uuid.UUID) int {
|
|
||||||
return slice.Ascending(a.String(), b.String())
|
|
||||||
})
|
|
||||||
activeUserIDs := make([]uuid.UUID, 0, len(appUsageUserIDs[appKey]))
|
|
||||||
for userID := range appUsageUserIDs[appKey] {
|
|
||||||
activeUserIDs = append(activeUserIDs, userID)
|
|
||||||
}
|
|
||||||
slices.SortFunc(activeUserIDs, func(a, b uuid.UUID) int {
|
|
||||||
return slice.Ascending(a.String(), b.String())
|
|
||||||
})
|
|
||||||
|
|
||||||
rows = append(rows, database.GetTemplateAppInsightsRow{
|
rows = append(rows, database.GetTemplateAppInsightsRow{
|
||||||
TemplateIDs: templateIDs,
|
TemplateIDs: templateRows[key].TemplateIDs,
|
||||||
ActiveUserIDs: activeUserIDs,
|
ActiveUsers: int64(len(uniqueSortedUUIDs(gr.ActiveUserIDs))),
|
||||||
AccessMethod: appKey.AccessMethod,
|
SlugOrPort: key.AppName,
|
||||||
SlugOrPort: appKey.SlugOrPort,
|
DisplayName: key.DisplayName,
|
||||||
DisplayName: sql.NullString{String: appKey.DisplayName, Valid: appKey.DisplayName != ""},
|
Icon: key.Icon,
|
||||||
Icon: sql.NullString{String: appKey.Icon, Valid: appKey.Icon != ""},
|
IsApp: key.IsApp,
|
||||||
IsApp: appKey.Slug != "",
|
UsageSeconds: gr.UsageSeconds,
|
||||||
UsageSeconds: usage,
|
|
||||||
})
|
})
|
||||||
}
|
}
|
||||||
|
|
||||||
// NOTE(mafredri): Add sorting if we decide on how to handle PostgreSQL collations.
|
// NOTE(mafredri): Add sorting if we decide on how to handle PostgreSQL collations.
|
||||||
// ORDER BY access_method, slug_or_port, display_name, icon, is_app
|
// ORDER BY slug_or_port, display_name, icon, is_app
|
||||||
return rows, nil
|
return rows, nil
|
||||||
}
|
}
|
||||||
|
|
||||||
@ -8174,7 +8356,7 @@ func (q *FakeQuerier) UpsertTemplateUsageStats(ctx context.Context) error {
|
|||||||
return err
|
return err
|
||||||
}
|
}
|
||||||
// CROSS JOIN generate_series
|
// CROSS JOIN generate_series
|
||||||
for t := was.SessionStartedAt; t.Before(was.SessionEndedAt); t = t.Add(time.Minute) {
|
for t := was.SessionStartedAt.Truncate(time.Minute); t.Before(was.SessionEndedAt); t = t.Add(time.Minute) {
|
||||||
// WHERE
|
// WHERE
|
||||||
if t.Before(latestStart) || t.After(now) || t.Equal(now) {
|
if t.Before(latestStart) || t.After(now) || t.Equal(now) {
|
||||||
continue
|
continue
|
||||||
|
@ -1698,81 +1698,118 @@ func (q *sqlQuerier) UpdateGroupByID(ctx context.Context, arg UpdateGroupByIDPar
|
|||||||
}
|
}
|
||||||
|
|
||||||
const getTemplateAppInsights = `-- name: GetTemplateAppInsights :many
|
const getTemplateAppInsights = `-- name: GetTemplateAppInsights :many
|
||||||
WITH app_stats_by_user_and_agent AS (
|
WITH
|
||||||
SELECT
|
app_insights AS (
|
||||||
s.start_time,
|
SELECT
|
||||||
60 as seconds,
|
tus.user_id,
|
||||||
w.template_id,
|
array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids,
|
||||||
was.user_id,
|
app_usage.key::text AS app_name,
|
||||||
was.agent_id,
|
COALESCE(wa.display_name, '') AS display_name,
|
||||||
was.access_method,
|
COALESCE(wa.icon, '') AS icon,
|
||||||
was.slug_or_port,
|
(wa.slug IS NOT NULL)::boolean AS is_app,
|
||||||
wa.display_name,
|
-- See motivation in GetTemplateInsights for LEAST(SUM(n), 30).
|
||||||
wa.icon,
|
LEAST(SUM(app_usage.value::int), 30) AS app_usage_mins
|
||||||
(wa.slug IS NOT NULL)::boolean AS is_app
|
FROM
|
||||||
FROM workspace_app_stats was
|
template_usage_stats AS tus, jsonb_each(app_usage_mins) AS app_usage
|
||||||
JOIN workspaces w ON (
|
LEFT JOIN LATERAL (
|
||||||
w.id = was.workspace_id
|
-- The joins in this query are necessary to associate an app with a
|
||||||
AND CASE WHEN COALESCE(array_length($1::uuid[], 1), 0) > 0 THEN w.template_id = ANY($1::uuid[]) ELSE TRUE END
|
-- template, we use this to get the app metadata like display name
|
||||||
|
-- and icon.
|
||||||
|
SELECT
|
||||||
|
app.display_name,
|
||||||
|
app.icon,
|
||||||
|
app.slug
|
||||||
|
FROM
|
||||||
|
workspace_apps AS app
|
||||||
|
JOIN
|
||||||
|
workspace_agents AS agent
|
||||||
|
ON
|
||||||
|
agent.id = app.agent_id
|
||||||
|
JOIN
|
||||||
|
workspace_resources AS resource
|
||||||
|
ON
|
||||||
|
resource.id = agent.resource_id
|
||||||
|
JOIN
|
||||||
|
workspace_builds AS build
|
||||||
|
ON
|
||||||
|
build.job_id = resource.job_id
|
||||||
|
JOIN
|
||||||
|
workspaces AS workspace
|
||||||
|
ON
|
||||||
|
workspace.id = build.workspace_id
|
||||||
|
WHERE
|
||||||
|
-- Requires lateral join.
|
||||||
|
app.slug = app_usage.key
|
||||||
|
AND workspace.owner_id = tus.user_id
|
||||||
|
AND workspace.template_id = tus.template_id
|
||||||
|
ORDER BY
|
||||||
|
app.created_at DESC
|
||||||
|
LIMIT 1
|
||||||
|
) AS wa
|
||||||
|
ON
|
||||||
|
true
|
||||||
|
WHERE
|
||||||
|
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.start_time, tus.user_id, app_usage.key::text, wa.display_name, wa.icon, wa.slug
|
||||||
|
),
|
||||||
|
templates AS (
|
||||||
|
SELECT
|
||||||
|
app_name,
|
||||||
|
display_name,
|
||||||
|
icon,
|
||||||
|
is_app,
|
||||||
|
array_agg(DISTINCT template_id)::uuid[] AS template_ids
|
||||||
|
FROM
|
||||||
|
app_insights, unnest(template_ids) AS template_id
|
||||||
|
GROUP BY
|
||||||
|
app_name, display_name, icon, is_app
|
||||||
)
|
)
|
||||||
-- We do a left join here because we want to include user IDs that have used
|
|
||||||
-- e.g. ports when counting active users.
|
|
||||||
LEFT JOIN workspace_apps wa ON (
|
|
||||||
wa.agent_id = was.agent_id
|
|
||||||
AND wa.slug = was.slug_or_port
|
|
||||||
)
|
|
||||||
-- 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, was.agent_id, was.access_method, was.slug_or_port, wa.display_name, wa.icon, wa.slug
|
|
||||||
)
|
|
||||||
|
|
||||||
SELECT
|
SELECT
|
||||||
array_agg(DISTINCT template_id)::uuid[] AS template_ids,
|
t.template_ids,
|
||||||
-- Return IDs so we can combine this with GetTemplateInsights.
|
COUNT(DISTINCT ai.user_id) AS active_users,
|
||||||
array_agg(DISTINCT user_id)::uuid[] AS active_user_ids,
|
ai.app_name AS slug_or_port,
|
||||||
access_method,
|
ai.display_name,
|
||||||
slug_or_port,
|
ai.icon,
|
||||||
display_name,
|
ai.is_app,
|
||||||
icon,
|
(SUM(ai.app_usage_mins) * 60)::bigint AS usage_seconds
|
||||||
is_app,
|
FROM
|
||||||
SUM(seconds) AS usage_seconds
|
app_insights AS ai
|
||||||
FROM app_stats_by_user_and_agent
|
JOIN
|
||||||
GROUP BY access_method, slug_or_port, display_name, icon, is_app
|
templates AS t
|
||||||
|
ON
|
||||||
|
ai.app_name = t.app_name
|
||||||
|
AND ai.display_name = t.display_name
|
||||||
|
AND ai.icon = t.icon
|
||||||
|
AND ai.is_app = t.is_app
|
||||||
|
GROUP BY
|
||||||
|
t.template_ids, ai.app_name, ai.display_name, ai.icon, ai.is_app
|
||||||
`
|
`
|
||||||
|
|
||||||
type GetTemplateAppInsightsParams struct {
|
type GetTemplateAppInsightsParams struct {
|
||||||
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
|
|
||||||
StartTime time.Time `db:"start_time" json:"start_time"`
|
StartTime time.Time `db:"start_time" json:"start_time"`
|
||||||
EndTime time.Time `db:"end_time" json:"end_time"`
|
EndTime time.Time `db:"end_time" json:"end_time"`
|
||||||
|
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
|
||||||
}
|
}
|
||||||
|
|
||||||
type GetTemplateAppInsightsRow struct {
|
type GetTemplateAppInsightsRow struct {
|
||||||
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
|
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
|
||||||
ActiveUserIDs []uuid.UUID `db:"active_user_ids" json:"active_user_ids"`
|
ActiveUsers int64 `db:"active_users" json:"active_users"`
|
||||||
AccessMethod string `db:"access_method" json:"access_method"`
|
SlugOrPort string `db:"slug_or_port" json:"slug_or_port"`
|
||||||
SlugOrPort string `db:"slug_or_port" json:"slug_or_port"`
|
DisplayName string `db:"display_name" json:"display_name"`
|
||||||
DisplayName sql.NullString `db:"display_name" json:"display_name"`
|
Icon string `db:"icon" json:"icon"`
|
||||||
Icon sql.NullString `db:"icon" json:"icon"`
|
IsApp bool `db:"is_app" json:"is_app"`
|
||||||
IsApp bool `db:"is_app" json:"is_app"`
|
UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"`
|
||||||
UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"`
|
|
||||||
}
|
}
|
||||||
|
|
||||||
// GetTemplateAppInsights returns the aggregate usage of each app in a given
|
// GetTemplateAppInsights returns the aggregate usage of each app in a given
|
||||||
// timeframe. The result can be filtered on template_ids, meaning only user data
|
// timeframe. The result can be filtered on template_ids, meaning only user data
|
||||||
// from workspaces based on those templates will be included.
|
// from workspaces based on those templates will be included.
|
||||||
func (q *sqlQuerier) GetTemplateAppInsights(ctx context.Context, arg GetTemplateAppInsightsParams) ([]GetTemplateAppInsightsRow, error) {
|
func (q *sqlQuerier) GetTemplateAppInsights(ctx context.Context, arg GetTemplateAppInsightsParams) ([]GetTemplateAppInsightsRow, error) {
|
||||||
rows, err := q.db.QueryContext(ctx, getTemplateAppInsights, pq.Array(arg.TemplateIDs), arg.StartTime, arg.EndTime)
|
rows, err := q.db.QueryContext(ctx, getTemplateAppInsights, arg.StartTime, arg.EndTime, pq.Array(arg.TemplateIDs))
|
||||||
if err != nil {
|
if err != nil {
|
||||||
return nil, err
|
return nil, err
|
||||||
}
|
}
|
||||||
@ -1782,8 +1819,7 @@ func (q *sqlQuerier) GetTemplateAppInsights(ctx context.Context, arg GetTemplate
|
|||||||
var i GetTemplateAppInsightsRow
|
var i GetTemplateAppInsightsRow
|
||||||
if err := rows.Scan(
|
if err := rows.Scan(
|
||||||
pq.Array(&i.TemplateIDs),
|
pq.Array(&i.TemplateIDs),
|
||||||
pq.Array(&i.ActiveUserIDs),
|
&i.ActiveUsers,
|
||||||
&i.AccessMethod,
|
|
||||||
&i.SlugOrPort,
|
&i.SlugOrPort,
|
||||||
&i.DisplayName,
|
&i.DisplayName,
|
||||||
&i.Icon,
|
&i.Icon,
|
||||||
|
@ -193,57 +193,95 @@ GROUP BY template_id;
|
|||||||
-- GetTemplateAppInsights returns the aggregate usage of each app in a given
|
-- GetTemplateAppInsights returns the aggregate usage of each app in a given
|
||||||
-- timeframe. The result can be filtered on template_ids, meaning only user data
|
-- timeframe. The result can be filtered on template_ids, meaning only user data
|
||||||
-- from workspaces based on those templates will be included.
|
-- from workspaces based on those templates will be included.
|
||||||
WITH app_stats_by_user_and_agent AS (
|
WITH
|
||||||
SELECT
|
app_insights AS (
|
||||||
s.start_time,
|
SELECT
|
||||||
60 as seconds,
|
tus.user_id,
|
||||||
w.template_id,
|
array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids,
|
||||||
was.user_id,
|
app_usage.key::text AS app_name,
|
||||||
was.agent_id,
|
COALESCE(wa.display_name, '') AS display_name,
|
||||||
was.access_method,
|
COALESCE(wa.icon, '') AS icon,
|
||||||
was.slug_or_port,
|
(wa.slug IS NOT NULL)::boolean AS is_app,
|
||||||
wa.display_name,
|
-- See motivation in GetTemplateInsights for LEAST(SUM(n), 30).
|
||||||
wa.icon,
|
LEAST(SUM(app_usage.value::int), 30) AS app_usage_mins
|
||||||
(wa.slug IS NOT NULL)::boolean AS is_app
|
FROM
|
||||||
FROM workspace_app_stats was
|
template_usage_stats AS tus, jsonb_each(app_usage_mins) AS app_usage
|
||||||
JOIN workspaces w ON (
|
LEFT JOIN LATERAL (
|
||||||
w.id = was.workspace_id
|
-- The joins in this query are necessary to associate an app with a
|
||||||
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN w.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
|
-- template, we use this to get the app metadata like display name
|
||||||
|
-- and icon.
|
||||||
|
SELECT
|
||||||
|
app.display_name,
|
||||||
|
app.icon,
|
||||||
|
app.slug
|
||||||
|
FROM
|
||||||
|
workspace_apps AS app
|
||||||
|
JOIN
|
||||||
|
workspace_agents AS agent
|
||||||
|
ON
|
||||||
|
agent.id = app.agent_id
|
||||||
|
JOIN
|
||||||
|
workspace_resources AS resource
|
||||||
|
ON
|
||||||
|
resource.id = agent.resource_id
|
||||||
|
JOIN
|
||||||
|
workspace_builds AS build
|
||||||
|
ON
|
||||||
|
build.job_id = resource.job_id
|
||||||
|
JOIN
|
||||||
|
workspaces AS workspace
|
||||||
|
ON
|
||||||
|
workspace.id = build.workspace_id
|
||||||
|
WHERE
|
||||||
|
-- Requires lateral join.
|
||||||
|
app.slug = app_usage.key
|
||||||
|
AND workspace.owner_id = tus.user_id
|
||||||
|
AND workspace.template_id = tus.template_id
|
||||||
|
ORDER BY
|
||||||
|
app.created_at DESC
|
||||||
|
LIMIT 1
|
||||||
|
) AS wa
|
||||||
|
ON
|
||||||
|
true
|
||||||
|
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.start_time, tus.user_id, app_usage.key::text, wa.display_name, wa.icon, wa.slug
|
||||||
|
),
|
||||||
|
templates AS (
|
||||||
|
SELECT
|
||||||
|
app_name,
|
||||||
|
display_name,
|
||||||
|
icon,
|
||||||
|
is_app,
|
||||||
|
array_agg(DISTINCT template_id)::uuid[] AS template_ids
|
||||||
|
FROM
|
||||||
|
app_insights, unnest(template_ids) AS template_id
|
||||||
|
GROUP BY
|
||||||
|
app_name, display_name, icon, is_app
|
||||||
)
|
)
|
||||||
-- We do a left join here because we want to include user IDs that have used
|
|
||||||
-- e.g. ports when counting active users.
|
|
||||||
LEFT JOIN workspace_apps wa ON (
|
|
||||||
wa.agent_id = was.agent_id
|
|
||||||
AND wa.slug = was.slug_or_port
|
|
||||||
)
|
|
||||||
-- 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 >= @start_time::timestamptz
|
|
||||||
-- Subtract one minute because the series only contains the start time.
|
|
||||||
AND s.start_time < (@end_time::timestamptz) - '1 minute'::interval
|
|
||||||
GROUP BY s.start_time, w.template_id, was.user_id, was.agent_id, was.access_method, was.slug_or_port, wa.display_name, wa.icon, wa.slug
|
|
||||||
)
|
|
||||||
|
|
||||||
SELECT
|
SELECT
|
||||||
array_agg(DISTINCT template_id)::uuid[] AS template_ids,
|
t.template_ids,
|
||||||
-- Return IDs so we can combine this with GetTemplateInsights.
|
COUNT(DISTINCT ai.user_id) AS active_users,
|
||||||
array_agg(DISTINCT user_id)::uuid[] AS active_user_ids,
|
ai.app_name AS slug_or_port,
|
||||||
access_method,
|
ai.display_name,
|
||||||
slug_or_port,
|
ai.icon,
|
||||||
display_name,
|
ai.is_app,
|
||||||
icon,
|
(SUM(ai.app_usage_mins) * 60)::bigint AS usage_seconds
|
||||||
is_app,
|
FROM
|
||||||
SUM(seconds) AS usage_seconds
|
app_insights AS ai
|
||||||
FROM app_stats_by_user_and_agent
|
JOIN
|
||||||
GROUP BY access_method, slug_or_port, display_name, icon, is_app;
|
templates AS t
|
||||||
|
ON
|
||||||
|
ai.app_name = t.app_name
|
||||||
|
AND ai.display_name = t.display_name
|
||||||
|
AND ai.icon = t.icon
|
||||||
|
AND ai.is_app = t.is_app
|
||||||
|
GROUP BY
|
||||||
|
t.template_ids, ai.app_name, ai.display_name, ai.icon, ai.is_app;
|
||||||
|
|
||||||
-- name: GetTemplateAppInsightsByTemplate :many
|
-- name: GetTemplateAppInsightsByTemplate :many
|
||||||
WITH app_stats_by_user_and_agent AS (
|
WITH app_stats_by_user_and_agent AS (
|
||||||
|
@ -468,17 +468,14 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage
|
|||||||
//
|
//
|
||||||
// ORDER BY access_method, slug_or_port, display_name, icon, is_app
|
// ORDER BY access_method, slug_or_port, display_name, icon, is_app
|
||||||
slices.SortFunc(appUsage, func(a, b database.GetTemplateAppInsightsRow) int {
|
slices.SortFunc(appUsage, func(a, b database.GetTemplateAppInsightsRow) int {
|
||||||
if a.AccessMethod != b.AccessMethod {
|
|
||||||
return strings.Compare(a.AccessMethod, b.AccessMethod)
|
|
||||||
}
|
|
||||||
if a.SlugOrPort != b.SlugOrPort {
|
if a.SlugOrPort != b.SlugOrPort {
|
||||||
return strings.Compare(a.SlugOrPort, b.SlugOrPort)
|
return strings.Compare(a.SlugOrPort, b.SlugOrPort)
|
||||||
}
|
}
|
||||||
if a.DisplayName.String != b.DisplayName.String {
|
if a.DisplayName != b.DisplayName {
|
||||||
return strings.Compare(a.DisplayName.String, b.DisplayName.String)
|
return strings.Compare(a.DisplayName, b.DisplayName)
|
||||||
}
|
}
|
||||||
if a.Icon.String != b.Icon.String {
|
if a.Icon != b.Icon {
|
||||||
return strings.Compare(a.Icon.String, b.Icon.String)
|
return strings.Compare(a.Icon, b.Icon)
|
||||||
}
|
}
|
||||||
if !a.IsApp && b.IsApp {
|
if !a.IsApp && b.IsApp {
|
||||||
return -1
|
return -1
|
||||||
@ -496,9 +493,9 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage
|
|||||||
apps = append(apps, codersdk.TemplateAppUsage{
|
apps = append(apps, codersdk.TemplateAppUsage{
|
||||||
TemplateIDs: app.TemplateIDs,
|
TemplateIDs: app.TemplateIDs,
|
||||||
Type: codersdk.TemplateAppsTypeApp,
|
Type: codersdk.TemplateAppsTypeApp,
|
||||||
DisplayName: app.DisplayName.String,
|
DisplayName: app.DisplayName,
|
||||||
Slug: app.SlugOrPort,
|
Slug: app.SlugOrPort,
|
||||||
Icon: app.Icon.String,
|
Icon: app.Icon,
|
||||||
Seconds: app.UsageSeconds,
|
Seconds: app.UsageSeconds,
|
||||||
})
|
})
|
||||||
}
|
}
|
||||||
|
Reference in New Issue
Block a user