feat(coderd): add template app usage to insights (#9138)

Fixes #8658
This commit is contained in:
Mathias Fredriksson
2023-08-21 15:08:58 +03:00
committed by GitHub
parent 4de7de420e
commit 03453b1e02
15 changed files with 741 additions and 118 deletions

View File

@ -1173,6 +1173,25 @@ func (q *querier) GetTailnetClientsForAgent(ctx context.Context, agentID uuid.UU
return q.db.GetTailnetClientsForAgent(ctx, agentID)
}
func (q *querier) GetTemplateAppInsights(ctx context.Context, arg database.GetTemplateAppInsightsParams) ([]database.GetTemplateAppInsightsRow, error) {
for _, templateID := range arg.TemplateIDs {
template, err := q.db.GetTemplateByID(ctx, templateID)
if err != nil {
return nil, err
}
if err := q.authorizeContext(ctx, rbac.ActionUpdate, template); err != nil {
return nil, err
}
}
if len(arg.TemplateIDs) == 0 {
if err := q.authorizeContext(ctx, rbac.ActionUpdate, rbac.ResourceTemplate.All()); err != nil {
return nil, err
}
}
return q.db.GetTemplateAppInsights(ctx, arg)
}
// Only used by metrics cache.
func (q *querier) GetTemplateAverageBuildTime(ctx context.Context, arg database.GetTemplateAverageBuildTimeParams) (database.GetTemplateAverageBuildTimeRow, error) {
if err := q.authorizeContext(ctx, rbac.ActionRead, rbac.ResourceSystem); err != nil {

View File

@ -549,6 +549,19 @@ func (q *FakeQuerier) getWorkspaceAgentsByResourceIDsNoLock(_ context.Context, r
return workspaceAgents, nil
}
func (q *FakeQuerier) getWorkspaceAppByAgentIDAndSlugNoLock(_ context.Context, arg database.GetWorkspaceAppByAgentIDAndSlugParams) (database.WorkspaceApp, error) {
for _, app := range q.workspaceApps {
if app.AgentID != arg.AgentID {
continue
}
if app.Slug != arg.Slug {
continue
}
return app, nil
}
return database.WorkspaceApp{}, sql.ErrNoRows
}
func (q *FakeQuerier) getProvisionerJobByIDNoLock(_ context.Context, id uuid.UUID) (database.ProvisionerJob, error) {
for _, provisionerJob := range q.provisionerJobs {
if provisionerJob.ID != id {
@ -1966,6 +1979,125 @@ func (*FakeQuerier) GetTailnetClientsForAgent(context.Context, uuid.UUID) ([]dat
return nil, ErrUnimplemented
}
func (q *FakeQuerier) GetTemplateAppInsights(ctx context.Context, arg database.GetTemplateAppInsightsParams) ([]database.GetTemplateAppInsightsRow, error) {
err := validateDatabaseType(arg)
if err != nil {
return nil, err
}
q.mutex.RLock()
defer q.mutex.RUnlock()
type appKey struct {
AccessMethod string
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 {
// (was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
// OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
// OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
if !(((s.SessionStartedAt.After(arg.StartTime) || s.SessionStartedAt.Equal(arg.StartTime)) && s.SessionStartedAt.Before(arg.EndTime)) ||
(s.SessionEndedAt.After(arg.StartTime) && s.SessionEndedAt.Before(arg.EndTime)) ||
(s.SessionStartedAt.Before(arg.StartTime) && (s.SessionEndedAt.After(arg.EndTime) || s.SessionEndedAt.Equal(arg.EndTime)))) {
continue
}
w, err := q.getWorkspaceByIDNoLock(ctx, s.WorkspaceID)
if err != nil {
return nil, err
}
app, _ := q.getWorkspaceAppByAgentIDAndSlugNoLock(ctx, database.GetWorkspaceAppByAgentIDAndSlugParams{
AgentID: s.AgentID,
Slug: s.SlugOrPort,
})
key := uniqueKey{
TemplateID: w.TemplateID,
UserID: s.UserID,
AgentID: s.AgentID,
AppKey: appKey{
AccessMethod: s.AccessMethod,
SlugOrPort: s.SlugOrPort,
Slug: app.Slug,
DisplayName: app.DisplayName,
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] = 300 // 5 minutes.
t = t.Add(5 * time.Minute)
}
}
appUsageTemplateIDs := make(map[appKey]map[uuid.UUID]struct{})
appUsageUserIDs := make(map[appKey]map[uuid.UUID]struct{})
appUsage := make(map[appKey]int64)
for uniqueKey, usage := range appUsageIntervalsByUserAgentApp {
for _, seconds := range usage {
if appUsageTemplateIDs[uniqueKey.AppKey] == nil {
appUsageTemplateIDs[uniqueKey.AppKey] = make(map[uuid.UUID]struct{})
}
appUsageTemplateIDs[uniqueKey.AppKey][uniqueKey.TemplateID] = struct{}{}
if appUsageUserIDs[uniqueKey.AppKey] == nil {
appUsageUserIDs[uniqueKey.AppKey] = make(map[uuid.UUID]struct{})
}
appUsageUserIDs[uniqueKey.AppKey][uniqueKey.UserID] = struct{}{}
appUsage[uniqueKey.AppKey] += seconds
}
}
var rows []database.GetTemplateAppInsightsRow
for appKey, usage := range appUsage {
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{
TemplateIDs: templateIDs,
ActiveUserIDs: activeUserIDs,
AccessMethod: appKey.AccessMethod,
SlugOrPort: appKey.SlugOrPort,
DisplayName: sql.NullString{String: appKey.DisplayName, Valid: appKey.DisplayName != ""},
Icon: sql.NullString{String: appKey.Icon, Valid: appKey.Icon != ""},
IsApp: appKey.Slug != "",
UsageSeconds: usage,
})
}
return rows, nil
}
func (q *FakeQuerier) GetTemplateAverageBuildTime(ctx context.Context, arg database.GetTemplateAverageBuildTimeParams) (database.GetTemplateAverageBuildTimeRow, error) {
if err := validateDatabaseType(arg); err != nil {
return database.GetTemplateAverageBuildTimeRow{}, err
@ -2093,12 +2225,15 @@ func (q *FakeQuerier) GetTemplateDAUs(_ context.Context, arg database.GetTemplat
return rs, nil
}
func (q *FakeQuerier) GetTemplateDailyInsights(_ context.Context, arg database.GetTemplateDailyInsightsParams) ([]database.GetTemplateDailyInsightsRow, error) {
func (q *FakeQuerier) GetTemplateDailyInsights(ctx context.Context, arg database.GetTemplateDailyInsightsParams) ([]database.GetTemplateDailyInsightsRow, error) {
err := validateDatabaseType(arg)
if err != nil {
return nil, err
}
q.mutex.RLock()
defer q.mutex.RUnlock()
type dailyStat struct {
startTime, endTime time.Time
userSet map[uuid.UUID]struct{}
@ -2133,6 +2268,37 @@ func (q *FakeQuerier) GetTemplateDailyInsights(_ context.Context, arg database.G
}
}
for _, s := range q.workspaceAppStats {
// (was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
// OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
// OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
if !(((s.SessionStartedAt.After(arg.StartTime) || s.SessionStartedAt.Equal(arg.StartTime)) && s.SessionStartedAt.Before(arg.EndTime)) ||
(s.SessionEndedAt.After(arg.StartTime) && s.SessionEndedAt.Before(arg.EndTime)) ||
(s.SessionStartedAt.Before(arg.StartTime) && (s.SessionEndedAt.After(arg.EndTime) || s.SessionEndedAt.Equal(arg.EndTime)))) {
continue
}
for _, ds := range dailyStats {
// (was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
// OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
// OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
if !(((s.SessionStartedAt.After(arg.StartTime) || s.SessionStartedAt.Equal(arg.StartTime)) && s.SessionStartedAt.Before(arg.EndTime)) ||
(s.SessionEndedAt.After(arg.StartTime) && s.SessionEndedAt.Before(arg.EndTime)) ||
(s.SessionStartedAt.Before(arg.StartTime) && (s.SessionEndedAt.After(arg.EndTime) || s.SessionEndedAt.Equal(arg.EndTime)))) {
continue
}
w, err := q.getWorkspaceByIDNoLock(ctx, s.WorkspaceID)
if err != nil {
return nil, err
}
ds.userSet[s.UserID] = struct{}{}
ds.templateIDSet[w.TemplateID] = struct{}{}
break
}
}
var result []database.GetTemplateDailyInsightsRow
for _, ds := range dailyStats {
templateIDs := make([]uuid.UUID, 0, len(ds.templateIDSet))
@ -2201,9 +2367,14 @@ func (q *FakeQuerier) GetTemplateInsights(_ context.Context, arg database.GetTem
slices.SortFunc(templateIDs, func(a, b uuid.UUID) int {
return slice.Ascending(a.String(), b.String())
})
activeUserIDs := make([]uuid.UUID, 0, len(appUsageIntervalsByUser))
for userID := range appUsageIntervalsByUser {
activeUserIDs = append(activeUserIDs, userID)
}
result := database.GetTemplateInsightsRow{
TemplateIDs: templateIDs,
ActiveUsers: int64(len(appUsageIntervalsByUser)),
TemplateIDs: templateIDs,
ActiveUserIDs: activeUserIDs,
}
for _, intervals := range appUsageIntervalsByUser {
for _, interval := range intervals {
@ -3075,7 +3246,7 @@ func (q *FakeQuerier) GetWorkspaceAgentsInLatestBuildByWorkspaceID(ctx context.C
return agents, nil
}
func (q *FakeQuerier) GetWorkspaceAppByAgentIDAndSlug(_ context.Context, arg database.GetWorkspaceAppByAgentIDAndSlugParams) (database.WorkspaceApp, error) {
func (q *FakeQuerier) GetWorkspaceAppByAgentIDAndSlug(ctx context.Context, arg database.GetWorkspaceAppByAgentIDAndSlugParams) (database.WorkspaceApp, error) {
if err := validateDatabaseType(arg); err != nil {
return database.WorkspaceApp{}, err
}
@ -3083,16 +3254,7 @@ func (q *FakeQuerier) GetWorkspaceAppByAgentIDAndSlug(_ context.Context, arg dat
q.mutex.RLock()
defer q.mutex.RUnlock()
for _, app := range q.workspaceApps {
if app.AgentID != arg.AgentID {
continue
}
if app.Slug != arg.Slug {
continue
}
return app, nil
}
return database.WorkspaceApp{}, sql.ErrNoRows
return q.getWorkspaceAppByAgentIDAndSlugNoLock(ctx, arg)
}
func (q *FakeQuerier) GetWorkspaceAppsByAgentID(_ context.Context, id uuid.UUID) ([]database.WorkspaceApp, error) {

View File

@ -599,6 +599,13 @@ func (m metricsStore) GetTailnetClientsForAgent(ctx context.Context, agentID uui
return m.s.GetTailnetClientsForAgent(ctx, agentID)
}
func (m metricsStore) GetTemplateAppInsights(ctx context.Context, arg database.GetTemplateAppInsightsParams) ([]database.GetTemplateAppInsightsRow, error) {
start := time.Now()
r0, r1 := m.s.GetTemplateAppInsights(ctx, arg)
m.queryLatencies.WithLabelValues("GetTemplateAppInsights").Observe(time.Since(start).Seconds())
return r0, r1
}
func (m metricsStore) GetTemplateAverageBuildTime(ctx context.Context, arg database.GetTemplateAverageBuildTimeParams) (database.GetTemplateAverageBuildTimeRow, error) {
start := time.Now()
buildTime, err := m.s.GetTemplateAverageBuildTime(ctx, arg)

View File

@ -1196,6 +1196,21 @@ func (mr *MockStoreMockRecorder) GetTailnetClientsForAgent(arg0, arg1 interface{
return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetTailnetClientsForAgent", reflect.TypeOf((*MockStore)(nil).GetTailnetClientsForAgent), arg0, arg1)
}
// GetTemplateAppInsights mocks base method.
func (m *MockStore) GetTemplateAppInsights(arg0 context.Context, arg1 database.GetTemplateAppInsightsParams) ([]database.GetTemplateAppInsightsRow, error) {
m.ctrl.T.Helper()
ret := m.ctrl.Call(m, "GetTemplateAppInsights", arg0, arg1)
ret0, _ := ret[0].([]database.GetTemplateAppInsightsRow)
ret1, _ := ret[1].(error)
return ret0, ret1
}
// GetTemplateAppInsights indicates an expected call of GetTemplateAppInsights.
func (mr *MockStoreMockRecorder) GetTemplateAppInsights(arg0, arg1 interface{}) *gomock.Call {
mr.mock.ctrl.T.Helper()
return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetTemplateAppInsights", reflect.TypeOf((*MockStore)(nil).GetTemplateAppInsights), arg0, arg1)
}
// GetTemplateAverageBuildTime mocks base method.
func (m *MockStore) GetTemplateAverageBuildTime(arg0 context.Context, arg1 database.GetTemplateAverageBuildTimeParams) (database.GetTemplateAverageBuildTimeRow, error) {
m.ctrl.T.Helper()

View File

@ -107,6 +107,10 @@ type sqlcQuerier interface {
GetServiceBanner(ctx context.Context) (string, error)
GetTailnetAgents(ctx context.Context, id uuid.UUID) ([]TailnetAgent, error)
GetTailnetClientsForAgent(ctx context.Context, agentID uuid.UUID) ([]TailnetClient, error)
// GetTemplateAppInsights returns the aggregate usage of each app in a given
// timeframe. The result can be filtered on template_ids, meaning only user data
// from workspaces based on those templates will be included.
GetTemplateAppInsights(ctx context.Context, arg GetTemplateAppInsightsParams) ([]GetTemplateAppInsightsRow, error)
GetTemplateAverageBuildTime(ctx context.Context, arg GetTemplateAverageBuildTimeParams) (GetTemplateAverageBuildTimeRow, error)
GetTemplateByID(ctx context.Context, id uuid.UUID) (Template, error)
GetTemplateByOrganizationAndName(ctx context.Context, arg GetTemplateByOrganizationAndNameParams) (Template, error)
@ -117,7 +121,8 @@ type sqlcQuerier interface {
// interval/template, it will be included in the results with 0 active users.
GetTemplateDailyInsights(ctx context.Context, arg GetTemplateDailyInsightsParams) ([]GetTemplateDailyInsightsRow, error)
// 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).
// in use during a minute, we will add 5 minutes to the total usage for that
// session/app (per user).
GetTemplateInsights(ctx context.Context, arg GetTemplateInsightsParams) (GetTemplateInsightsRow, error)
// GetTemplateParameterInsights does for each template in a given timeframe,
// look for the latest workspace build (for every workspace) that has been

View File

@ -1461,21 +1461,143 @@ func (q *sqlQuerier) UpdateGroupByID(ctx context.Context, arg UpdateGroupByIDPar
return i, err
}
const getTemplateDailyInsights = `-- name: GetTemplateDailyInsights :many
WITH d AS (
-- sqlc workaround, use SELECT generate_series instead of SELECT * FROM generate_series.
-- Subtract 1 second from end_time to avoid including the next interval in the results.
SELECT generate_series($1::timestamptz, ($2::timestamptz) - '1 second'::interval, '1 day'::interval) AS d
), ts AS (
const getTemplateAppInsights = `-- name: GetTemplateAppInsights :many
WITH ts AS (
SELECT
d::timestamptz AS from_,
CASE WHEN (d + '1 day'::interval)::timestamptz <= $2::timestamptz THEN (d + '1 day'::interval)::timestamptz ELSE $2::timestamptz END AS to_
FROM d
), usage_by_day AS (
(d::timestamptz + '5 minute'::interval) AS to_,
EXTRACT(epoch FROM '5 minute'::interval) AS seconds
FROM
-- Subtract 1 second from end_time to avoid including the next interval in the results.
generate_series($1::timestamptz, ($2::timestamptz) - '1 second'::interval, '5 minute'::interval) d
), app_stats_by_user_and_agent AS (
SELECT
ts.from_,
ts.to_,
ts.seconds,
w.template_id,
was.user_id,
was.agent_id,
was.access_method,
was.slug_or_port,
wa.display_name,
wa.icon,
(wa.slug IS NOT NULL)::boolean AS is_app
FROM ts
JOIN workspace_app_stats was ON (
(was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
)
JOIN workspaces w ON (
w.id = was.workspace_id
AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN w.template_id = ANY($3::uuid[]) ELSE TRUE END
)
-- 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
)
WHERE
-- We already handle timeframe in the join, but we use an additional
-- check against a static timeframe to help speed up the query.
(was.session_started_at >= $1 AND was.session_started_at < $2)
OR (was.session_ended_at > $1 AND was.session_ended_at < $2)
OR (was.session_started_at < $1 AND was.session_ended_at >= $2)
GROUP BY ts.from_, ts.to_, ts.seconds, w.template_id, was.user_id, was.agent_id, was.access_method, was.slug_or_port, wa.display_name, wa.icon, wa.slug
)
SELECT
array_agg(DISTINCT template_id)::uuid[] AS template_ids,
-- Return IDs so we can combine this with GetTemplateInsights.
array_agg(DISTINCT user_id)::uuid[] AS active_user_ids,
access_method,
slug_or_port,
display_name,
icon,
is_app,
SUM(seconds) AS usage_seconds
FROM app_stats_by_user_and_agent
GROUP BY access_method, slug_or_port, display_name, icon, is_app
`
type GetTemplateAppInsightsParams struct {
StartTime time.Time `db:"start_time" json:"start_time"`
EndTime time.Time `db:"end_time" json:"end_time"`
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
}
type GetTemplateAppInsightsRow struct {
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
ActiveUserIDs []uuid.UUID `db:"active_user_ids" json:"active_user_ids"`
AccessMethod string `db:"access_method" json:"access_method"`
SlugOrPort string `db:"slug_or_port" json:"slug_or_port"`
DisplayName sql.NullString `db:"display_name" json:"display_name"`
Icon sql.NullString `db:"icon" json:"icon"`
IsApp bool `db:"is_app" json:"is_app"`
UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"`
}
// GetTemplateAppInsights returns the aggregate usage of each app in a given
// timeframe. The result can be filtered on template_ids, meaning only user data
// from workspaces based on those templates will be included.
func (q *sqlQuerier) GetTemplateAppInsights(ctx context.Context, arg GetTemplateAppInsightsParams) ([]GetTemplateAppInsightsRow, error) {
rows, err := q.db.QueryContext(ctx, getTemplateAppInsights, arg.StartTime, arg.EndTime, pq.Array(arg.TemplateIDs))
if err != nil {
return nil, err
}
defer rows.Close()
var items []GetTemplateAppInsightsRow
for rows.Next() {
var i GetTemplateAppInsightsRow
if err := rows.Scan(
pq.Array(&i.TemplateIDs),
pq.Array(&i.ActiveUserIDs),
&i.AccessMethod,
&i.SlugOrPort,
&i.DisplayName,
&i.Icon,
&i.IsApp,
&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 getTemplateDailyInsights = `-- name: GetTemplateDailyInsights :many
WITH ts AS (
SELECT
d::timestamptz AS from_,
CASE
WHEN (d::timestamptz + '1 day'::interval) <= $1::timestamptz
THEN (d::timestamptz + '1 day'::interval)
ELSE $1::timestamptz
END AS to_
FROM
-- Subtract 1 second from end_time to avoid including the next interval in the results.
generate_series($2::timestamptz, ($1::timestamptz) - '1 second'::interval, '1 day'::interval) AS d
), unflattened_usage_by_day AS (
-- We select data from both workspace agent stats and workspace app stats to
-- get a complete picture of usage. This matches how usage is calculated by
-- the combination of GetTemplateInsights and GetTemplateAppInsights. We use
-- a union all to avoid a costly distinct operation.
--
-- Note that one query must perform a left join so that all intervals are
-- present at least once.
SELECT
ts.from_, ts.to_,
was.user_id,
array_agg(was.template_id) AS template_ids
was.template_id,
was.user_id
FROM ts
LEFT JOIN workspace_agent_stats was ON (
was.created_at >= ts.from_
@ -1483,33 +1605,39 @@ WITH d AS (
AND was.connection_count > 0
AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN was.template_id = ANY($3::uuid[]) ELSE TRUE END
)
GROUP BY ts.from_, ts.to_, was.user_id
), template_ids AS (
GROUP BY ts.from_, ts.to_, was.template_id, was.user_id
UNION ALL
SELECT
template_usage_by_day.from_,
array_agg(template_id) AS ids
FROM (
SELECT DISTINCT
from_,
unnest(template_ids) AS template_id
FROM usage_by_day
) AS template_usage_by_day
WHERE template_id IS NOT NULL
GROUP BY template_usage_by_day.from_
ts.from_, ts.to_,
w.template_id,
was.user_id
FROM ts
JOIN workspace_app_stats was ON (
(was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
)
JOIN workspaces w ON (
w.id = was.workspace_id
AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN w.template_id = ANY($3::uuid[]) ELSE TRUE END
)
GROUP BY ts.from_, ts.to_, w.template_id, was.user_id
)
SELECT
from_ AS start_time,
to_ AS end_time,
COALESCE((SELECT template_ids.ids FROM template_ids WHERE template_ids.from_ = usage_by_day.from_), '{}')::uuid[] AS template_ids,
array_remove(array_agg(DISTINCT template_id), NULL)::uuid[] AS template_ids,
COUNT(DISTINCT user_id) AS active_users
FROM usage_by_day
FROM unflattened_usage_by_day
GROUP BY from_, to_
`
type GetTemplateDailyInsightsParams struct {
StartTime time.Time `db:"start_time" json:"start_time"`
EndTime time.Time `db:"end_time" json:"end_time"`
StartTime time.Time `db:"start_time" json:"start_time"`
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
}
@ -1525,7 +1653,7 @@ type GetTemplateDailyInsightsRow struct {
// that interval will be less than 24 hours. If there is no data for a selected
// interval/template, it will be included in the results with 0 active users.
func (q *sqlQuerier) GetTemplateDailyInsights(ctx context.Context, arg GetTemplateDailyInsightsParams) ([]GetTemplateDailyInsightsRow, error) {
rows, err := q.db.QueryContext(ctx, getTemplateDailyInsights, arg.StartTime, arg.EndTime, pq.Array(arg.TemplateIDs))
rows, err := q.db.QueryContext(ctx, getTemplateDailyInsights, arg.EndTime, arg.StartTime, pq.Array(arg.TemplateIDs))
if err != nil {
return nil, err
}
@ -1553,16 +1681,15 @@ func (q *sqlQuerier) GetTemplateDailyInsights(ctx context.Context, arg GetTempla
}
const getTemplateInsights = `-- name: GetTemplateInsights :one
WITH d AS (
-- Subtract 1 second from end_time to avoid including the next interval in the results.
SELECT generate_series($1::timestamptz, ($2::timestamptz) - '1 second'::interval, '5 minute'::interval) AS d
), ts AS (
WITH ts AS (
SELECT
d::timestamptz AS from_,
(d + '5 minute'::interval)::timestamptz AS to_,
(d::timestamptz + '5 minute'::interval) AS to_,
EXTRACT(epoch FROM '5 minute'::interval) AS seconds
FROM d
), usage_by_user AS (
FROM
-- Subtract 1 second from end_time to avoid including the next interval in the results.
generate_series($1::timestamptz, ($2::timestamptz) - '1 second'::interval, '5 minute'::interval) d
), agent_stats_by_interval_and_user AS (
SELECT
ts.from_,
ts.to_,
@ -1579,21 +1706,27 @@ WITH d AS (
AND was.connection_count > 0
AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN was.template_id = ANY($3::uuid[]) ELSE TRUE END
)
WHERE
-- We already handle created_at in the join, but we use an additional
-- check against a static timeframe to help speed up the query.
was.created_at >= $1
AND was.created_at < $2
GROUP BY ts.from_, ts.to_, ts.seconds, was.user_id
), template_ids AS (
SELECT array_agg(DISTINCT template_id) AS ids
FROM usage_by_user, unnest(template_ids) template_id
FROM agent_stats_by_interval_and_user, unnest(template_ids) template_id
WHERE template_id IS NOT NULL
)
SELECT
COALESCE((SELECT ids FROM template_ids), '{}')::uuid[] AS template_ids,
COUNT(DISTINCT user_id) AS active_users,
-- Return IDs so we can combine this with GetTemplateAppInsights.
COALESCE(array_agg(DISTINCT user_id), '{}')::uuid[] AS active_user_ids,
COALESCE(SUM(usage_vscode_seconds), 0)::bigint AS usage_vscode_seconds,
COALESCE(SUM(usage_jetbrains_seconds), 0)::bigint AS usage_jetbrains_seconds,
COALESCE(SUM(usage_reconnecting_pty_seconds), 0)::bigint AS usage_reconnecting_pty_seconds,
COALESCE(SUM(usage_ssh_seconds), 0)::bigint AS usage_ssh_seconds
FROM usage_by_user
FROM agent_stats_by_interval_and_user
`
type GetTemplateInsightsParams struct {
@ -1604,7 +1737,7 @@ type GetTemplateInsightsParams struct {
type GetTemplateInsightsRow struct {
TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"`
ActiveUsers int64 `db:"active_users" json:"active_users"`
ActiveUserIDs []uuid.UUID `db:"active_user_ids" json:"active_user_ids"`
UsageVscodeSeconds int64 `db:"usage_vscode_seconds" json:"usage_vscode_seconds"`
UsageJetbrainsSeconds int64 `db:"usage_jetbrains_seconds" json:"usage_jetbrains_seconds"`
UsageReconnectingPtySeconds int64 `db:"usage_reconnecting_pty_seconds" json:"usage_reconnecting_pty_seconds"`
@ -1612,13 +1745,14 @@ type GetTemplateInsightsRow struct {
}
// 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).
// in use during a minute, we will add 5 minutes to the total usage for that
// session/app (per user).
func (q *sqlQuerier) GetTemplateInsights(ctx context.Context, arg GetTemplateInsightsParams) (GetTemplateInsightsRow, error) {
row := q.db.QueryRowContext(ctx, getTemplateInsights, arg.StartTime, arg.EndTime, pq.Array(arg.TemplateIDs))
var i GetTemplateInsightsRow
err := row.Scan(
pq.Array(&i.TemplateIDs),
&i.ActiveUsers,
pq.Array(&i.ActiveUserIDs),
&i.UsageVscodeSeconds,
&i.UsageJetbrainsSeconds,
&i.UsageReconnectingPtySeconds,
@ -1634,15 +1768,15 @@ WITH latest_workspace_builds AS (
wbmax.template_id,
wb.template_version_id
FROM (
SELECT
tv.template_id, wbmax.workspace_id, MAX(wbmax.build_number) as max_build_number
SELECT
tv.template_id, wbmax.workspace_id, MAX(wbmax.build_number) as max_build_number
FROM workspace_builds wbmax
JOIN template_versions tv ON (tv.id = wbmax.template_version_id)
WHERE
wbmax.created_at >= $1::timestamptz
AND wbmax.created_at < $2::timestamptz
AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN tv.template_id = ANY($3::uuid[]) ELSE TRUE END
GROUP BY tv.template_id, wbmax.workspace_id
GROUP BY tv.template_id, wbmax.workspace_id
) wbmax
JOIN workspace_builds wb ON (
wb.workspace_id = wbmax.workspace_id

View File

@ -23,17 +23,17 @@ ORDER BY user_id ASC;
-- name: GetTemplateInsights :one
-- 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 (
-- 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 (
-- in use during a minute, we will add 5 minutes to the total usage for that
-- session/app (per user).
WITH ts AS (
SELECT
d::timestamptz AS from_,
(d + '5 minute'::interval)::timestamptz AS to_,
(d::timestamptz + '5 minute'::interval) AS to_,
EXTRACT(epoch FROM '5 minute'::interval) AS seconds
FROM d
), usage_by_user AS (
FROM
-- Subtract 1 second from end_time to avoid including the next interval in the results.
generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 second'::interval, '5 minute'::interval) d
), agent_stats_by_interval_and_user AS (
SELECT
ts.from_,
ts.to_,
@ -50,41 +50,119 @@ WITH d AS (
AND was.connection_count > 0
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN was.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
)
WHERE
-- We already handle created_at in the join, but we use an additional
-- check against a static timeframe to help speed up the query.
was.created_at >= @start_time
AND was.created_at < @end_time
GROUP BY ts.from_, ts.to_, ts.seconds, was.user_id
), template_ids AS (
SELECT array_agg(DISTINCT template_id) AS ids
FROM usage_by_user, unnest(template_ids) template_id
FROM agent_stats_by_interval_and_user, unnest(template_ids) template_id
WHERE template_id IS NOT NULL
)
SELECT
COALESCE((SELECT ids FROM template_ids), '{}')::uuid[] AS template_ids,
COUNT(DISTINCT user_id) AS active_users,
-- Return IDs so we can combine this with GetTemplateAppInsights.
COALESCE(array_agg(DISTINCT user_id), '{}')::uuid[] AS active_user_ids,
COALESCE(SUM(usage_vscode_seconds), 0)::bigint AS usage_vscode_seconds,
COALESCE(SUM(usage_jetbrains_seconds), 0)::bigint AS usage_jetbrains_seconds,
COALESCE(SUM(usage_reconnecting_pty_seconds), 0)::bigint AS usage_reconnecting_pty_seconds,
COALESCE(SUM(usage_ssh_seconds), 0)::bigint AS usage_ssh_seconds
FROM usage_by_user;
FROM agent_stats_by_interval_and_user;
-- name: GetTemplateAppInsights :many
-- GetTemplateAppInsights returns the aggregate usage of each app in a given
-- timeframe. The result can be filtered on template_ids, meaning only user data
-- from workspaces based on those templates will be included.
WITH ts AS (
SELECT
d::timestamptz AS from_,
(d::timestamptz + '5 minute'::interval) AS to_,
EXTRACT(epoch FROM '5 minute'::interval) AS seconds
FROM
-- Subtract 1 second from end_time to avoid including the next interval in the results.
generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 second'::interval, '5 minute'::interval) d
), app_stats_by_user_and_agent AS (
SELECT
ts.from_,
ts.to_,
ts.seconds,
w.template_id,
was.user_id,
was.agent_id,
was.access_method,
was.slug_or_port,
wa.display_name,
wa.icon,
(wa.slug IS NOT NULL)::boolean AS is_app
FROM ts
JOIN workspace_app_stats was ON (
(was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
)
JOIN workspaces w ON (
w.id = was.workspace_id
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN w.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
)
-- 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
)
WHERE
-- We already handle timeframe in the join, but we use an additional
-- check against a static timeframe to help speed up the query.
(was.session_started_at >= @start_time AND was.session_started_at < @end_time)
OR (was.session_ended_at > @start_time AND was.session_ended_at < @end_time)
OR (was.session_started_at < @start_time AND was.session_ended_at >= @end_time)
GROUP BY ts.from_, ts.to_, ts.seconds, w.template_id, was.user_id, was.agent_id, was.access_method, was.slug_or_port, wa.display_name, wa.icon, wa.slug
)
SELECT
array_agg(DISTINCT template_id)::uuid[] AS template_ids,
-- Return IDs so we can combine this with GetTemplateInsights.
array_agg(DISTINCT user_id)::uuid[] AS active_user_ids,
access_method,
slug_or_port,
display_name,
icon,
is_app,
SUM(seconds) AS usage_seconds
FROM app_stats_by_user_and_agent
GROUP BY access_method, slug_or_port, display_name, icon, is_app;
-- name: GetTemplateDailyInsights :many
-- GetTemplateDailyInsights returns all daily intervals between start and end
-- time, if end time is a partial day, it will be included in the results and
-- that interval will be less than 24 hours. If there is no data for a selected
-- 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.
-- 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 (
WITH ts AS (
SELECT
d::timestamptz AS from_,
CASE WHEN (d + '1 day'::interval)::timestamptz <= @end_time::timestamptz THEN (d + '1 day'::interval)::timestamptz ELSE @end_time::timestamptz END AS to_
FROM d
), usage_by_day AS (
CASE
WHEN (d::timestamptz + '1 day'::interval) <= @end_time::timestamptz
THEN (d::timestamptz + '1 day'::interval)
ELSE @end_time::timestamptz
END AS to_
FROM
-- Subtract 1 second from end_time to avoid including the next interval in the results.
generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 second'::interval, '1 day'::interval) AS d
), unflattened_usage_by_day AS (
-- We select data from both workspace agent stats and workspace app stats to
-- get a complete picture of usage. This matches how usage is calculated by
-- the combination of GetTemplateInsights and GetTemplateAppInsights. We use
-- a union all to avoid a costly distinct operation.
--
-- Note that one query must perform a left join so that all intervals are
-- present at least once.
SELECT
ts.*,
was.user_id,
array_agg(was.template_id) AS template_ids
was.template_id,
was.user_id
FROM ts
LEFT JOIN workspace_agent_stats was ON (
was.created_at >= ts.from_
@ -92,30 +170,35 @@ WITH d AS (
AND was.connection_count > 0
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN was.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
)
GROUP BY ts.from_, ts.to_, was.user_id
), template_ids AS (
GROUP BY ts.from_, ts.to_, was.template_id, was.user_id
UNION ALL
SELECT
template_usage_by_day.from_,
array_agg(template_id) AS ids
FROM (
SELECT DISTINCT
from_,
unnest(template_ids) AS template_id
FROM usage_by_day
) AS template_usage_by_day
WHERE template_id IS NOT NULL
GROUP BY template_usage_by_day.from_
ts.*,
w.template_id,
was.user_id
FROM ts
JOIN workspace_app_stats was ON (
(was.session_started_at >= ts.from_ AND was.session_started_at < ts.to_)
OR (was.session_ended_at > ts.from_ AND was.session_ended_at < ts.to_)
OR (was.session_started_at < ts.from_ AND was.session_ended_at >= ts.to_)
)
JOIN workspaces w ON (
w.id = was.workspace_id
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN w.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
)
GROUP BY ts.from_, ts.to_, w.template_id, was.user_id
)
SELECT
from_ AS start_time,
to_ AS end_time,
COALESCE((SELECT template_ids.ids FROM template_ids WHERE template_ids.from_ = usage_by_day.from_), '{}')::uuid[] AS template_ids,
array_remove(array_agg(DISTINCT template_id), NULL)::uuid[] AS template_ids,
COUNT(DISTINCT user_id) AS active_users
FROM usage_by_day
FROM unflattened_usage_by_day
GROUP BY from_, to_;
-- name: GetTemplateParameterInsights :many
-- GetTemplateParameterInsights does for each template in a given timeframe,
-- look for the latest workspace build (for every workspace) that has been
@ -127,15 +210,15 @@ WITH latest_workspace_builds AS (
wbmax.template_id,
wb.template_version_id
FROM (
SELECT
tv.template_id, wbmax.workspace_id, MAX(wbmax.build_number) as max_build_number
SELECT
tv.template_id, wbmax.workspace_id, MAX(wbmax.build_number) as max_build_number
FROM workspace_builds wbmax
JOIN template_versions tv ON (tv.id = wbmax.template_version_id)
WHERE
wbmax.created_at >= @start_time::timestamptz
AND wbmax.created_at < @end_time::timestamptz
AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN tv.template_id = ANY(@template_ids::uuid[]) ELSE TRUE END
GROUP BY tv.template_id, wbmax.workspace_id
GROUP BY tv.template_id, wbmax.workspace_id
) wbmax
JOIN workspace_builds wb ON (
wb.workspace_id = wbmax.workspace_id

View File

@ -71,6 +71,7 @@ overrides:
eof: EOF
locked_ttl: LockedTTL
template_ids: TemplateIDs
active_user_ids: ActiveUserIDs
sql:
- schema: "./dump.sql"