From 90521174411f29d62a8e6896238c38e2c46bae98 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Mon, 18 Mar 2024 20:27:21 +0200 Subject: [PATCH 01/19] feat(coderd/database): add `template_usage_stats` table and rollup query --- coderd/database/dbauthz/dbauthz.go | 30 ++ coderd/database/dbmem/dbmem.go | 37 +++ coderd/database/dbmetrics/dbmetrics.go | 14 + coderd/database/dbmock/dbmock.go | 29 ++ coderd/database/dump.sql | 53 ++- .../000202_template_usage_stats.down.sql | 1 + .../000202_template_usage_stats.up.sql | 36 ++ coderd/database/models.go | 28 ++ coderd/database/querier.go | 6 + coderd/database/queries.sql.go | 310 ++++++++++++++++++ coderd/database/queries/insights.sql | 261 +++++++++++++++ coderd/database/sqlc.yaml | 3 + coderd/database/types.go | 22 ++ coderd/database/unique_constraint.go | 2 + 14 files changed, 831 insertions(+), 1 deletion(-) create mode 100644 coderd/database/migrations/000202_template_usage_stats.down.sql create mode 100644 coderd/database/migrations/000202_template_usage_stats.up.sql diff --git a/coderd/database/dbauthz/dbauthz.go b/coderd/database/dbauthz/dbauthz.go index 2dd15e073b802a..93dd6617c4991f 100644 --- a/coderd/database/dbauthz/dbauthz.go +++ b/coderd/database/dbauthz/dbauthz.go @@ -1617,6 +1617,29 @@ func (q *querier) GetTemplateParameterInsights(ctx context.Context, arg database return q.db.GetTemplateParameterInsights(ctx, arg) } +func (q *querier) GetTemplateUsageStats(ctx context.Context, arg database.GetTemplateUsageStatsParams) ([]database.TemplateUsageStat, error) { + // Used by dbrollup tests, use same safe-guard as other insights endpoints. + // For auditors, check read template_insights, and fall back to update template. + if err := q.authorizeContext(ctx, rbac.ActionRead, rbac.ResourceTemplateInsights); err != nil { + 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.GetTemplateUsageStats(ctx, arg) +} + func (q *querier) GetTemplateVersionByID(ctx context.Context, tvid uuid.UUID) (database.TemplateVersion, error) { tv, err := q.db.GetTemplateVersionByID(ctx, tvid) if err != nil { @@ -3413,6 +3436,13 @@ func (q *querier) UpsertTailnetTunnel(ctx context.Context, arg database.UpsertTa return q.db.UpsertTailnetTunnel(ctx, arg) } +func (q *querier) UpsertTemplateUsageStats(ctx context.Context) error { + if err := q.authorizeContext(ctx, rbac.ActionUpdate, rbac.ResourceSystem); err != nil { + return err + } + return q.db.UpsertTemplateUsageStats(ctx) +} + func (q *querier) UpsertWorkspaceAgentPortShare(ctx context.Context, arg database.UpsertWorkspaceAgentPortShareParams) (database.WorkspaceAgentPortShare, error) { workspace, err := q.db.GetWorkspaceByID(ctx, arg.WorkspaceID) if err != nil { diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index ac53fa586fd40b..30567f81fc89f8 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -162,6 +162,7 @@ type data struct { templateVersionParameters []database.TemplateVersionParameter templateVersionVariables []database.TemplateVersionVariable templates []database.TemplateTable + templateUsageStats []database.TemplateUsageStat workspaceAgents []database.WorkspaceAgent workspaceAgentMetadata []database.WorkspaceAgentMetadatum workspaceAgentLogs []database.WorkspaceAgentLog @@ -3584,6 +3585,34 @@ func (q *FakeQuerier) GetTemplateParameterInsights(ctx context.Context, arg data return rows, nil } +func (q *FakeQuerier) GetTemplateUsageStats(_ context.Context, arg database.GetTemplateUsageStatsParams) ([]database.TemplateUsageStat, error) { + err := validateDatabaseType(arg) + if err != nil { + return nil, err + } + + q.mutex.RLock() + defer q.mutex.RUnlock() + + var stats []database.TemplateUsageStat + for _, stat := range q.templateUsageStats { + // Exclude all chunks that don't fall exactly within the range. + if stat.StartTime.Before(arg.StartTime) || stat.EndTime.After(arg.EndTime) { + continue + } + if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, stat.TemplateID) { + continue + } + stats = append(stats, stat) + } + + if len(stats) == 0 { + return nil, sql.ErrNoRows + } + + return stats, nil +} + func (q *FakeQuerier) GetTemplateVersionByID(ctx context.Context, templateVersionID uuid.UUID) (database.TemplateVersion, error) { q.mutex.RLock() defer q.mutex.RUnlock() @@ -7923,6 +7952,14 @@ func (*FakeQuerier) UpsertTailnetTunnel(_ context.Context, arg database.UpsertTa return database.TailnetTunnel{}, ErrUnimplemented } +func (q *FakeQuerier) UpsertTemplateUsageStats(_ context.Context) error { + q.mutex.Lock() + defer q.mutex.Unlock() + + // TODO(mafredri): Implement. + panic("not implemented") +} + func (q *FakeQuerier) UpsertWorkspaceAgentPortShare(_ context.Context, arg database.UpsertWorkspaceAgentPortShareParams) (database.WorkspaceAgentPortShare, error) { err := validateDatabaseType(arg) if err != nil { diff --git a/coderd/database/dbmetrics/dbmetrics.go b/coderd/database/dbmetrics/dbmetrics.go index 2350588511f920..5cd452d328e169 100644 --- a/coderd/database/dbmetrics/dbmetrics.go +++ b/coderd/database/dbmetrics/dbmetrics.go @@ -949,6 +949,13 @@ func (m metricsStore) GetTemplateParameterInsights(ctx context.Context, arg data return r0, r1 } +func (m metricsStore) GetTemplateUsageStats(ctx context.Context, arg database.GetTemplateUsageStatsParams) ([]database.TemplateUsageStat, error) { + start := time.Now() + r0, r1 := m.s.GetTemplateUsageStats(ctx, arg) + m.queryLatencies.WithLabelValues("GetTemplateUsageStats").Observe(time.Since(start).Seconds()) + return r0, r1 +} + func (m metricsStore) GetTemplateVersionByID(ctx context.Context, id uuid.UUID) (database.TemplateVersion, error) { start := time.Now() version, err := m.s.GetTemplateVersionByID(ctx, id) @@ -2234,6 +2241,13 @@ func (m metricsStore) UpsertTailnetTunnel(ctx context.Context, arg database.Upse return r0, r1 } +func (m metricsStore) UpsertTemplateUsageStats(ctx context.Context) error { + start := time.Now() + r0 := m.s.UpsertTemplateUsageStats(ctx) + m.queryLatencies.WithLabelValues("UpsertTemplateUsageStats").Observe(time.Since(start).Seconds()) + return r0 +} + func (m metricsStore) UpsertWorkspaceAgentPortShare(ctx context.Context, arg database.UpsertWorkspaceAgentPortShareParams) (database.WorkspaceAgentPortShare, error) { start := time.Now() r0, r1 := m.s.UpsertWorkspaceAgentPortShare(ctx, arg) diff --git a/coderd/database/dbmock/dbmock.go b/coderd/database/dbmock/dbmock.go index ba5b3c965c035c..32049ba0721b7b 100644 --- a/coderd/database/dbmock/dbmock.go +++ b/coderd/database/dbmock/dbmock.go @@ -1950,6 +1950,21 @@ func (mr *MockStoreMockRecorder) GetTemplateParameterInsights(arg0, arg1 any) *g return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetTemplateParameterInsights", reflect.TypeOf((*MockStore)(nil).GetTemplateParameterInsights), arg0, arg1) } +// GetTemplateUsageStats mocks base method. +func (m *MockStore) GetTemplateUsageStats(arg0 context.Context, arg1 database.GetTemplateUsageStatsParams) ([]database.TemplateUsageStat, error) { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "GetTemplateUsageStats", arg0, arg1) + ret0, _ := ret[0].([]database.TemplateUsageStat) + ret1, _ := ret[1].(error) + return ret0, ret1 +} + +// GetTemplateUsageStats indicates an expected call of GetTemplateUsageStats. +func (mr *MockStoreMockRecorder) GetTemplateUsageStats(arg0, arg1 any) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetTemplateUsageStats", reflect.TypeOf((*MockStore)(nil).GetTemplateUsageStats), arg0, arg1) +} + // GetTemplateUserRoles mocks base method. func (m *MockStore) GetTemplateUserRoles(arg0 context.Context, arg1 uuid.UUID) ([]database.TemplateUser, error) { m.ctrl.T.Helper() @@ -4694,6 +4709,20 @@ func (mr *MockStoreMockRecorder) UpsertTailnetTunnel(arg0, arg1 any) *gomock.Cal return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "UpsertTailnetTunnel", reflect.TypeOf((*MockStore)(nil).UpsertTailnetTunnel), arg0, arg1) } +// UpsertTemplateUsageStats mocks base method. +func (m *MockStore) UpsertTemplateUsageStats(arg0 context.Context) error { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "UpsertTemplateUsageStats", arg0) + ret0, _ := ret[0].(error) + return ret0 +} + +// UpsertTemplateUsageStats indicates an expected call of UpsertTemplateUsageStats. +func (mr *MockStoreMockRecorder) UpsertTemplateUsageStats(arg0 any) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "UpsertTemplateUsageStats", reflect.TypeOf((*MockStore)(nil).UpsertTemplateUsageStats), arg0) +} + // UpsertWorkspaceAgentPortShare mocks base method. func (m *MockStore) UpsertWorkspaceAgentPortShare(arg0 context.Context, arg1 database.UpsertWorkspaceAgentPortShareParams) (database.WorkspaceAgentPortShare, error) { m.ctrl.T.Helper() diff --git a/coderd/database/dump.sql b/coderd/database/dump.sql index 93e6ef23b20f7c..7159edc279233e 100644 --- a/coderd/database/dump.sql +++ b/coderd/database/dump.sql @@ -741,6 +741,47 @@ CREATE TABLE tailnet_tunnels ( updated_at timestamp with time zone NOT NULL ); +CREATE TABLE template_usage_stats ( + start_time timestamp with time zone NOT NULL, + end_time timestamp with time zone NOT NULL, + template_id uuid NOT NULL, + user_id uuid NOT NULL, + median_latency_ms real, + usage_mins smallint NOT NULL, + ssh_mins smallint NOT NULL, + sftp_mins smallint NOT NULL, + reconnecting_pty_mins smallint NOT NULL, + vscode_mins smallint NOT NULL, + jetbrains_mins smallint NOT NULL, + app_usage_mins jsonb +); + +COMMENT ON TABLE template_usage_stats IS 'Records aggregated usage statistics for templates/users. All usage is rounded up to the nearest minute.'; + +COMMENT ON COLUMN template_usage_stats.start_time IS 'Start time of the usage period.'; + +COMMENT ON COLUMN template_usage_stats.end_time IS 'End time of the usage period.'; + +COMMENT ON COLUMN template_usage_stats.template_id IS 'ID of the template being used.'; + +COMMENT ON COLUMN template_usage_stats.user_id IS 'ID of the user using the template.'; + +COMMENT ON COLUMN template_usage_stats.median_latency_ms IS 'Median latency the user is experiencing, in milliseconds. Null means no value was recorded.'; + +COMMENT ON COLUMN template_usage_stats.usage_mins IS 'Total minutes the user has been using the template.'; + +COMMENT ON COLUMN template_usage_stats.ssh_mins IS 'Total minutes the user has been using SSH.'; + +COMMENT ON COLUMN template_usage_stats.sftp_mins IS 'Total minutes the user has been using SFTP.'; + +COMMENT ON COLUMN template_usage_stats.reconnecting_pty_mins IS 'Total minutes the user has been using the reconnecting PTY.'; + +COMMENT ON COLUMN template_usage_stats.vscode_mins IS 'Total minutes the user has been using VSCode.'; + +COMMENT ON COLUMN template_usage_stats.jetbrains_mins IS 'Total minutes the user has been using JetBrains.'; + +COMMENT ON COLUMN template_usage_stats.app_usage_mins IS 'Object with app names as keys and total minutes used as values. Null means no app usage was recorded.'; + CREATE TABLE template_version_parameters ( template_version_id uuid NOT NULL, name text NOT NULL, @@ -1468,6 +1509,9 @@ ALTER TABLE ONLY tailnet_peers ALTER TABLE ONLY tailnet_tunnels ADD CONSTRAINT tailnet_tunnels_pkey PRIMARY KEY (coordinator_id, src_id, dst_id); +ALTER TABLE ONLY template_usage_stats + ADD CONSTRAINT template_usage_stats_pkey PRIMARY KEY (start_time, template_id, user_id); + ALTER TABLE ONLY template_version_parameters ADD CONSTRAINT template_version_parameters_template_version_id_name_key UNIQUE (template_version_id, name); @@ -1590,6 +1634,14 @@ CREATE INDEX provisioner_job_logs_id_job_id_idx ON provisioner_job_logs USING bt CREATE INDEX provisioner_jobs_started_at_idx ON provisioner_jobs USING btree (started_at) WHERE (started_at IS NULL); +CREATE INDEX template_usage_stats_start_time_idx ON template_usage_stats USING btree (start_time DESC); + +COMMENT ON INDEX template_usage_stats_start_time_idx IS 'Index for querying MAX(start_time).'; + +CREATE UNIQUE INDEX template_usage_stats_start_time_template_id_user_id_idx ON template_usage_stats USING btree (start_time, template_id, user_id); + +COMMENT ON INDEX template_usage_stats_start_time_template_id_user_id_idx IS 'Index for primary key.'; + CREATE UNIQUE INDEX templates_organization_id_name_idx ON templates USING btree (organization_id, lower((name)::text)) WHERE (deleted = false); CREATE UNIQUE INDEX users_email_lower_idx ON users USING btree (lower(email)) WHERE (deleted = false); @@ -1795,4 +1847,3 @@ ALTER TABLE ONLY workspaces ALTER TABLE ONLY workspaces ADD CONSTRAINT workspaces_template_id_fkey FOREIGN KEY (template_id) REFERENCES templates(id) ON DELETE RESTRICT; - diff --git a/coderd/database/migrations/000202_template_usage_stats.down.sql b/coderd/database/migrations/000202_template_usage_stats.down.sql new file mode 100644 index 00000000000000..728b27a611a920 --- /dev/null +++ b/coderd/database/migrations/000202_template_usage_stats.down.sql @@ -0,0 +1 @@ +DROP TABLE template_usage_stats; diff --git a/coderd/database/migrations/000202_template_usage_stats.up.sql b/coderd/database/migrations/000202_template_usage_stats.up.sql new file mode 100644 index 00000000000000..1508bbbd63af0c --- /dev/null +++ b/coderd/database/migrations/000202_template_usage_stats.up.sql @@ -0,0 +1,36 @@ +CREATE TABLE template_usage_stats ( + start_time timestamptz NOT NULL, + end_time timestamptz NOT NULL, + template_id uuid NOT NULL, + user_id uuid NOT NULL, + median_latency_ms real NULL, + usage_mins smallint NOT NULL, + ssh_mins smallint NOT NULL, + sftp_mins smallint NOT NULL, + reconnecting_pty_mins smallint NOT NULL, + vscode_mins smallint NOT NULL, + jetbrains_mins smallint NOT NULL, + app_usage_mins jsonb NULL, + + PRIMARY KEY (start_time, template_id, user_id) +); + +COMMENT ON TABLE template_usage_stats IS 'Records aggregated usage statistics for templates/users. All usage is rounded up to the nearest minute.'; +COMMENT ON COLUMN template_usage_stats.start_time IS 'Start time of the usage period.'; +COMMENT ON COLUMN template_usage_stats.end_time IS 'End time of the usage period.'; +COMMENT ON COLUMN template_usage_stats.template_id IS 'ID of the template being used.'; +COMMENT ON COLUMN template_usage_stats.user_id IS 'ID of the user using the template.'; +COMMENT ON COLUMN template_usage_stats.median_latency_ms IS 'Median latency the user is experiencing, in milliseconds. Null means no value was recorded.'; +COMMENT ON COLUMN template_usage_stats.usage_mins IS 'Total minutes the user has been using the template.'; +COMMENT ON COLUMN template_usage_stats.ssh_mins IS 'Total minutes the user has been using SSH.'; +COMMENT ON COLUMN template_usage_stats.sftp_mins IS 'Total minutes the user has been using SFTP.'; +COMMENT ON COLUMN template_usage_stats.reconnecting_pty_mins IS 'Total minutes the user has been using the reconnecting PTY.'; +COMMENT ON COLUMN template_usage_stats.vscode_mins IS 'Total minutes the user has been using VSCode.'; +COMMENT ON COLUMN template_usage_stats.jetbrains_mins IS 'Total minutes the user has been using JetBrains.'; +COMMENT ON COLUMN template_usage_stats.app_usage_mins IS 'Object with app names as keys and total minutes used as values. Null means no app usage was recorded.'; + +CREATE UNIQUE INDEX ON template_usage_stats (start_time, template_id, user_id); +CREATE INDEX ON template_usage_stats (start_time DESC); + +COMMENT ON INDEX template_usage_stats_start_time_template_id_user_id_idx IS 'Index for primary key.'; +COMMENT ON INDEX template_usage_stats_start_time_idx IS 'Index for querying MAX(start_time).'; diff --git a/coderd/database/models.go b/coderd/database/models.go index 49eb5bf811fd25..18587b05ade1ae 100644 --- a/coderd/database/models.go +++ b/coderd/database/models.go @@ -2139,6 +2139,34 @@ type TemplateTable struct { MaxPortSharingLevel AppSharingLevel `db:"max_port_sharing_level" json:"max_port_sharing_level"` } +// Records aggregated usage statistics for templates/users. All usage is rounded up to the nearest minute. +type TemplateUsageStat struct { + // Start time of the usage period. + StartTime time.Time `db:"start_time" json:"start_time"` + // End time of the usage period. + EndTime time.Time `db:"end_time" json:"end_time"` + // ID of the template being used. + TemplateID uuid.UUID `db:"template_id" json:"template_id"` + // ID of the user using the template. + UserID uuid.UUID `db:"user_id" json:"user_id"` + // Median latency the user is experiencing, in milliseconds. Null means no value was recorded. + MedianLatencyMs sql.NullFloat64 `db:"median_latency_ms" json:"median_latency_ms"` + // Total minutes the user has been using the template. + UsageMins int16 `db:"usage_mins" json:"usage_mins"` + // Total minutes the user has been using SSH. + SshMins int16 `db:"ssh_mins" json:"ssh_mins"` + // Total minutes the user has been using SFTP. + SftpMins int16 `db:"sftp_mins" json:"sftp_mins"` + // Total minutes the user has been using the reconnecting PTY. + ReconnectingPtyMins int16 `db:"reconnecting_pty_mins" json:"reconnecting_pty_mins"` + // Total minutes the user has been using VSCode. + VscodeMins int16 `db:"vscode_mins" json:"vscode_mins"` + // Total minutes the user has been using JetBrains. + JetbrainsMins int16 `db:"jetbrains_mins" json:"jetbrains_mins"` + // Object with app names as keys and total minutes used as values. Null means no app usage was recorded. + AppUsageMins StringMapOfInt `db:"app_usage_mins" json:"app_usage_mins"` +} + // Joins in the username + avatar url of the created by user. type TemplateVersion struct { ID uuid.UUID `db:"id" json:"id"` diff --git a/coderd/database/querier.go b/coderd/database/querier.go index fc47f58204b68b..87d5d7771130df 100644 --- a/coderd/database/querier.go +++ b/coderd/database/querier.go @@ -193,6 +193,7 @@ type sqlcQuerier interface { // created in the timeframe and return the aggregate usage counts of parameter // values. GetTemplateParameterInsights(ctx context.Context, arg GetTemplateParameterInsightsParams) ([]GetTemplateParameterInsightsRow, error) + GetTemplateUsageStats(ctx context.Context, arg GetTemplateUsageStatsParams) ([]TemplateUsageStat, error) GetTemplateVersionByID(ctx context.Context, id uuid.UUID) (TemplateVersion, error) GetTemplateVersionByJobID(ctx context.Context, jobID uuid.UUID) (TemplateVersion, error) GetTemplateVersionByTemplateIDAndName(ctx context.Context, arg GetTemplateVersionByTemplateIDAndNameParams) (TemplateVersion, error) @@ -416,6 +417,11 @@ type sqlcQuerier interface { UpsertTailnetCoordinator(ctx context.Context, id uuid.UUID) (TailnetCoordinator, error) UpsertTailnetPeer(ctx context.Context, arg UpsertTailnetPeerParams) (TailnetPeer, error) UpsertTailnetTunnel(ctx context.Context, arg UpsertTailnetTunnelParams) (TailnetTunnel, error) + // This query aggregates the workspace_agent_stats and workspace_app_stats data + // into a single table for efficient storage and querying. Half-hour buckets are + // used to store the data, and the minutes are summed for each user and template + // combination. The result is stored in the template_usage_stats table. + UpsertTemplateUsageStats(ctx context.Context) error UpsertWorkspaceAgentPortShare(ctx context.Context, arg UpsertWorkspaceAgentPortShareParams) (WorkspaceAgentPortShare, error) } diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 057c10d267e4d5..ac095e3c89131c 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -2250,6 +2250,59 @@ func (q *sqlQuerier) GetTemplateParameterInsights(ctx context.Context, arg GetTe return items, nil } +const getTemplateUsageStats = `-- name: GetTemplateUsageStats :many +SELECT + start_time, end_time, template_id, user_id, median_latency_ms, usage_mins, ssh_mins, sftp_mins, reconnecting_pty_mins, vscode_mins, jetbrains_mins, app_usage_mins +FROM + template_usage_stats +WHERE + start_time >= $1::timestamptz + AND end_time <= $2::timestamptz + AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN template_id = ANY($3::uuid[]) ELSE TRUE END +` + +type GetTemplateUsageStatsParams 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"` +} + +func (q *sqlQuerier) GetTemplateUsageStats(ctx context.Context, arg GetTemplateUsageStatsParams) ([]TemplateUsageStat, error) { + rows, err := q.db.QueryContext(ctx, getTemplateUsageStats, arg.StartTime, arg.EndTime, pq.Array(arg.TemplateIDs)) + if err != nil { + return nil, err + } + defer rows.Close() + var items []TemplateUsageStat + for rows.Next() { + var i TemplateUsageStat + if err := rows.Scan( + &i.StartTime, + &i.EndTime, + &i.TemplateID, + &i.UserID, + &i.MedianLatencyMs, + &i.UsageMins, + &i.SshMins, + &i.SftpMins, + &i.ReconnectingPtyMins, + &i.VscodeMins, + &i.JetbrainsMins, + &i.AppUsageMins, + ); 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 getUserActivityInsights = `-- name: GetUserActivityInsights :many WITH app_stats AS ( SELECT @@ -2440,6 +2493,263 @@ func (q *sqlQuerier) GetUserLatencyInsights(ctx context.Context, arg GetUserLate return items, nil } +const upsertTemplateUsageStats = `-- name: UpsertTemplateUsageStats :exec +WITH + latest_start AS ( + SELECT + COALESCE( + MAX(start_time) - '1 hour'::interval, + NOW() - '6 months'::interval + ) AS t + FROM + template_usage_stats + ), + workspace_app_stat_buckets AS ( + SELECT + -- Truncate the minute to the nearest half hour, this is the bucket size + -- for the data. + date_trunc('hour', s.minute_bucket) + trunc(date_part('minute', s.minute_bucket) / 30) * 30 * '1 minute'::interval AS time_bucket, + w.template_id, + was.user_id, + -- Both app stats and agent stats track web terminal usage, but + -- by different means. The app stats value should be more + -- accurate so we don't want to discard it just yet. + CASE + WHEN was.access_method = 'terminal' + THEN '[terminal]' -- Unique name, app names can't contain brackets. + ELSE was.slug_or_port + END AS app_name, + COUNT(DISTINCT s.minute_bucket) AS app_minutes, + -- Store each unique minute bucket for later merge between datasets. + array_agg(DISTINCT s.minute_bucket) AS minute_buckets + FROM + workspace_app_stats AS was + JOIN + workspaces AS w + ON + w.id = was.workspace_id + -- Generate a series of minute buckets for each session for computing the + -- mintes/bucket. + CROSS JOIN + 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 + ) AS s(minute_bucket) + WHERE + -- s.minute_bucket >= @start_time::timestamptz + -- AND s.minute_bucket < @end_time::timestamptz + s.minute_bucket >= (SELECT t FROM latest_start) + AND s.minute_bucket < NOW() + GROUP BY + time_bucket, w.template_id, was.user_id, was.access_method, was.slug_or_port + ), + agent_stats_buckets AS ( + SELECT + -- Truncate the minute to the nearest half hour, this is the bucket size + -- for the data. + date_trunc('hour', created_at) + trunc(date_part('minute', created_at) / 30) * 30 * '1 minute'::interval AS time_bucket, + template_id, + user_id, + -- Store each unique minute bucket for later merge between datasets. + array_agg( + DISTINCT CASE + WHEN + session_count_ssh > 0 + -- TODO(mafredri): Enable when we have the column. + -- OR session_count_sftp > 0 + OR session_count_reconnecting_pty > 0 + OR session_count_vscode > 0 + OR session_count_jetbrains > 0 + THEN + date_trunc('minute', created_at) + ELSE + NULL + END + ) AS minute_buckets, + COUNT(DISTINCT CASE WHEN session_count_ssh > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS ssh_mins, + -- TODO(mafredri): Enable when we have the column. + -- COUNT(DISTINCT CASE WHEN session_count_sftp > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS sftp_mins, + COUNT(DISTINCT CASE WHEN session_count_reconnecting_pty > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS reconnecting_pty_mins, + COUNT(DISTINCT CASE WHEN session_count_vscode > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS vscode_mins, + COUNT(DISTINCT CASE WHEN session_count_jetbrains > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS jetbrains_mins, + -- NOTE(mafredri): The agent stats are currently very unreliable, and + -- sometimes the connections are missing, even during active sessions. + -- Since we can't fully rely on this, we check for "any connection + -- during this half-hour". A better solution here would be preferable. + MAX(connection_count) > 0 AS has_connection + FROM + workspace_agent_stats + WHERE + -- created_at >= @start_time::timestamptz + -- AND created_at < @end_time::timestamptz + created_at >= (SELECT t FROM latest_start) + AND created_at < NOW() + -- Inclusion criteria to filter out empty results. + AND ( + session_count_ssh > 0 + -- TODO(mafredri): Enable when we have the column. + -- OR session_count_sftp > 0 + OR session_count_reconnecting_pty > 0 + OR session_count_vscode > 0 + OR session_count_jetbrains > 0 + ) + GROUP BY + time_bucket, template_id, user_id + ), + stats AS ( + SELECT + stats.time_bucket AS start_time, + stats.time_bucket + '30 minutes'::interval AS end_time, + stats.template_id, + stats.user_id, + -- Sum/distinct to handle zero/duplicate values due union and to unnest. + COUNT(DISTINCT minute_bucket) AS usage_mins, + array_agg(DISTINCT minute_bucket) AS minute_buckets, + SUM(DISTINCT stats.ssh_mins) AS ssh_mins, + SUM(DISTINCT stats.sftp_mins) AS sftp_mins, + SUM(DISTINCT stats.reconnecting_pty_mins) AS reconnecting_pty_mins, + SUM(DISTINCT stats.vscode_mins) AS vscode_mins, + SUM(DISTINCT stats.jetbrains_mins) AS jetbrains_mins, + -- This is what we unnested, re-nest as json. + jsonb_object_agg(stats.app_name, stats.app_minutes) FILTER (WHERE stats.app_name IS NOT NULL) AS app_usage_mins + FROM ( + SELECT + time_bucket, + template_id, + user_id, + 0 AS ssh_mins, + 0 AS sftp_mins, + 0 AS reconnecting_pty_mins, + 0 AS vscode_mins, + 0 AS jetbrains_mins, + app_name, + app_minutes, + minute_buckets + FROM + workspace_app_stat_buckets + + UNION ALL + + SELECT + time_bucket, + template_id, + user_id, + ssh_mins, + -- TODO(mafredri): Enable when we have the column. + 0 AS sftp_mins, + reconnecting_pty_mins, + vscode_mins, + jetbrains_mins, + NULL AS app_name, + NULL AS app_minutes, + minute_buckets + FROM + agent_stats_buckets + WHERE + -- See note in the agent_stats_buckets CTE. + has_connection + ) AS stats, unnest(minute_buckets) AS minute_bucket + GROUP BY + stats.time_bucket, stats.template_id, stats.user_id + ), + minute_buckets AS ( + -- Create distinct minute buckets for user-activity, so we can filter out + -- irrelevant latencies. + SELECT DISTINCT ON (stats.start_time, stats.template_id, stats.user_id, minute_bucket) + stats.start_time, + stats.template_id, + stats.user_id, + minute_bucket + FROM + stats, unnest(minute_buckets) AS minute_bucket + ), + latencies AS ( + -- Select all non-zero latencies for all the minutes that a user used the + -- workspace in some way. + SELECT + mb.start_time, + mb.template_id, + mb.user_id, + -- TODO(mafredri): We're doing medians on medians here, we may want to + -- improve upon this at some point. + PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY was.connection_median_latency_ms)::real AS median_latency_ms + FROM + minute_buckets AS mb + JOIN + workspace_agent_stats AS was + ON + date_trunc('minute', was.created_at) = mb.minute_bucket + AND was.template_id = mb.template_id + AND was.user_id = mb.user_id + AND was.connection_median_latency_ms >= 0 + GROUP BY + mb.start_time, mb.template_id, mb.user_id + ) + +INSERT INTO template_usage_stats AS tus ( + start_time, + end_time, + template_id, + user_id, + usage_mins, + median_latency_ms, + ssh_mins, + sftp_mins, + reconnecting_pty_mins, + vscode_mins, + jetbrains_mins, + app_usage_mins +) ( + SELECT + stats.start_time, + stats.end_time, + stats.template_id, + stats.user_id, + stats.usage_mins, + latencies.median_latency_ms, + stats.ssh_mins, + stats.sftp_mins, + stats.reconnecting_pty_mins, + stats.vscode_mins, + stats.jetbrains_mins, + stats.app_usage_mins + FROM + stats + LEFT JOIN + latencies + ON + -- The latencies group-by ensures there at most one row. + latencies.start_time = stats.start_time + AND latencies.template_id = stats.template_id + AND latencies.user_id = stats.user_id +) +ON CONFLICT + (start_time, template_id, user_id) +DO UPDATE +SET + usage_mins = EXCLUDED.usage_mins, + median_latency_ms = EXCLUDED.median_latency_ms, + ssh_mins = EXCLUDED.ssh_mins, + sftp_mins = EXCLUDED.sftp_mins, + reconnecting_pty_mins = EXCLUDED.reconnecting_pty_mins, + vscode_mins = EXCLUDED.vscode_mins, + jetbrains_mins = EXCLUDED.jetbrains_mins, + app_usage_mins = EXCLUDED.app_usage_mins +WHERE + (tus.*) IS DISTINCT FROM (EXCLUDED.*) +` + +// This query aggregates the workspace_agent_stats and workspace_app_stats data +// into a single table for efficient storage and querying. Half-hour buckets are +// used to store the data, and the minutes are summed for each user and template +// combination. The result is stored in the template_usage_stats table. +func (q *sqlQuerier) UpsertTemplateUsageStats(ctx context.Context) error { + _, err := q.db.ExecContext(ctx, upsertTemplateUsageStats) + return err +} + const getJFrogXrayScanByWorkspaceAndAgentID = `-- name: GetJFrogXrayScanByWorkspaceAndAgentID :one SELECT agent_id, workspace_id, critical, high, medium, results_url diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index f81141d06f42ac..bffb2bf5fdb5db 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -329,6 +329,267 @@ SELECT FROM unflattened_usage_by_interval GROUP BY from_, to_; +-- name: GetTemplateUsageStats :many +SELECT + * +FROM + template_usage_stats +WHERE + start_time >= @start_time::timestamptz + AND end_time <= @end_time::timestamptz + AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN template_id = ANY(@template_ids::uuid[]) ELSE TRUE END; + +-- name: UpsertTemplateUsageStats :exec +-- This query aggregates the workspace_agent_stats and workspace_app_stats data +-- into a single table for efficient storage and querying. Half-hour buckets are +-- used to store the data, and the minutes are summed for each user and template +-- combination. The result is stored in the template_usage_stats table. +WITH + latest_start AS ( + SELECT + COALESCE( + MAX(start_time) - '1 hour'::interval, + NOW() - '6 months'::interval + ) AS t + FROM + template_usage_stats + ), + workspace_app_stat_buckets AS ( + SELECT + -- Truncate the minute to the nearest half hour, this is the bucket size + -- for the data. + date_trunc('hour', s.minute_bucket) + trunc(date_part('minute', s.minute_bucket) / 30) * 30 * '1 minute'::interval AS time_bucket, + w.template_id, + was.user_id, + -- Both app stats and agent stats track web terminal usage, but + -- by different means. The app stats value should be more + -- accurate so we don't want to discard it just yet. + CASE + WHEN was.access_method = 'terminal' + THEN '[terminal]' -- Unique name, app names can't contain brackets. + ELSE was.slug_or_port + END AS app_name, + COUNT(DISTINCT s.minute_bucket) AS app_minutes, + -- Store each unique minute bucket for later merge between datasets. + array_agg(DISTINCT s.minute_bucket) AS minute_buckets + FROM + workspace_app_stats AS was + JOIN + workspaces AS w + ON + w.id = was.workspace_id + -- Generate a series of minute buckets for each session for computing the + -- mintes/bucket. + CROSS JOIN + 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 + ) AS s(minute_bucket) + WHERE + -- s.minute_bucket >= @start_time::timestamptz + -- AND s.minute_bucket < @end_time::timestamptz + s.minute_bucket >= (SELECT t FROM latest_start) + AND s.minute_bucket < NOW() + GROUP BY + time_bucket, w.template_id, was.user_id, was.access_method, was.slug_or_port + ), + agent_stats_buckets AS ( + SELECT + -- Truncate the minute to the nearest half hour, this is the bucket size + -- for the data. + date_trunc('hour', created_at) + trunc(date_part('minute', created_at) / 30) * 30 * '1 minute'::interval AS time_bucket, + template_id, + user_id, + -- Store each unique minute bucket for later merge between datasets. + array_agg( + DISTINCT CASE + WHEN + session_count_ssh > 0 + -- TODO(mafredri): Enable when we have the column. + -- OR session_count_sftp > 0 + OR session_count_reconnecting_pty > 0 + OR session_count_vscode > 0 + OR session_count_jetbrains > 0 + THEN + date_trunc('minute', created_at) + ELSE + NULL + END + ) AS minute_buckets, + COUNT(DISTINCT CASE WHEN session_count_ssh > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS ssh_mins, + -- TODO(mafredri): Enable when we have the column. + -- COUNT(DISTINCT CASE WHEN session_count_sftp > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS sftp_mins, + COUNT(DISTINCT CASE WHEN session_count_reconnecting_pty > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS reconnecting_pty_mins, + COUNT(DISTINCT CASE WHEN session_count_vscode > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS vscode_mins, + COUNT(DISTINCT CASE WHEN session_count_jetbrains > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS jetbrains_mins, + -- NOTE(mafredri): The agent stats are currently very unreliable, and + -- sometimes the connections are missing, even during active sessions. + -- Since we can't fully rely on this, we check for "any connection + -- during this half-hour". A better solution here would be preferable. + MAX(connection_count) > 0 AS has_connection + FROM + workspace_agent_stats + WHERE + -- created_at >= @start_time::timestamptz + -- AND created_at < @end_time::timestamptz + created_at >= (SELECT t FROM latest_start) + AND created_at < NOW() + -- Inclusion criteria to filter out empty results. + AND ( + session_count_ssh > 0 + -- TODO(mafredri): Enable when we have the column. + -- OR session_count_sftp > 0 + OR session_count_reconnecting_pty > 0 + OR session_count_vscode > 0 + OR session_count_jetbrains > 0 + ) + GROUP BY + time_bucket, template_id, user_id + ), + stats AS ( + SELECT + stats.time_bucket AS start_time, + stats.time_bucket + '30 minutes'::interval AS end_time, + stats.template_id, + stats.user_id, + -- Sum/distinct to handle zero/duplicate values due union and to unnest. + COUNT(DISTINCT minute_bucket) AS usage_mins, + array_agg(DISTINCT minute_bucket) AS minute_buckets, + SUM(DISTINCT stats.ssh_mins) AS ssh_mins, + SUM(DISTINCT stats.sftp_mins) AS sftp_mins, + SUM(DISTINCT stats.reconnecting_pty_mins) AS reconnecting_pty_mins, + SUM(DISTINCT stats.vscode_mins) AS vscode_mins, + SUM(DISTINCT stats.jetbrains_mins) AS jetbrains_mins, + -- This is what we unnested, re-nest as json. + jsonb_object_agg(stats.app_name, stats.app_minutes) FILTER (WHERE stats.app_name IS NOT NULL) AS app_usage_mins + FROM ( + SELECT + time_bucket, + template_id, + user_id, + 0 AS ssh_mins, + 0 AS sftp_mins, + 0 AS reconnecting_pty_mins, + 0 AS vscode_mins, + 0 AS jetbrains_mins, + app_name, + app_minutes, + minute_buckets + FROM + workspace_app_stat_buckets + + UNION ALL + + SELECT + time_bucket, + template_id, + user_id, + ssh_mins, + -- TODO(mafredri): Enable when we have the column. + 0 AS sftp_mins, + reconnecting_pty_mins, + vscode_mins, + jetbrains_mins, + NULL AS app_name, + NULL AS app_minutes, + minute_buckets + FROM + agent_stats_buckets + WHERE + -- See note in the agent_stats_buckets CTE. + has_connection + ) AS stats, unnest(minute_buckets) AS minute_bucket + GROUP BY + stats.time_bucket, stats.template_id, stats.user_id + ), + minute_buckets AS ( + -- Create distinct minute buckets for user-activity, so we can filter out + -- irrelevant latencies. + SELECT DISTINCT ON (stats.start_time, stats.template_id, stats.user_id, minute_bucket) + stats.start_time, + stats.template_id, + stats.user_id, + minute_bucket + FROM + stats, unnest(minute_buckets) AS minute_bucket + ), + latencies AS ( + -- Select all non-zero latencies for all the minutes that a user used the + -- workspace in some way. + SELECT + mb.start_time, + mb.template_id, + mb.user_id, + -- TODO(mafredri): We're doing medians on medians here, we may want to + -- improve upon this at some point. + PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY was.connection_median_latency_ms)::real AS median_latency_ms + FROM + minute_buckets AS mb + JOIN + workspace_agent_stats AS was + ON + date_trunc('minute', was.created_at) = mb.minute_bucket + AND was.template_id = mb.template_id + AND was.user_id = mb.user_id + AND was.connection_median_latency_ms >= 0 + GROUP BY + mb.start_time, mb.template_id, mb.user_id + ) + +INSERT INTO template_usage_stats AS tus ( + start_time, + end_time, + template_id, + user_id, + usage_mins, + median_latency_ms, + ssh_mins, + sftp_mins, + reconnecting_pty_mins, + vscode_mins, + jetbrains_mins, + app_usage_mins +) ( + SELECT + stats.start_time, + stats.end_time, + stats.template_id, + stats.user_id, + stats.usage_mins, + latencies.median_latency_ms, + stats.ssh_mins, + stats.sftp_mins, + stats.reconnecting_pty_mins, + stats.vscode_mins, + stats.jetbrains_mins, + stats.app_usage_mins + FROM + stats + LEFT JOIN + latencies + ON + -- The latencies group-by ensures there at most one row. + latencies.start_time = stats.start_time + AND latencies.template_id = stats.template_id + AND latencies.user_id = stats.user_id +) +ON CONFLICT + (start_time, template_id, user_id) +DO UPDATE +SET + usage_mins = EXCLUDED.usage_mins, + median_latency_ms = EXCLUDED.median_latency_ms, + ssh_mins = EXCLUDED.ssh_mins, + sftp_mins = EXCLUDED.sftp_mins, + reconnecting_pty_mins = EXCLUDED.reconnecting_pty_mins, + vscode_mins = EXCLUDED.vscode_mins, + jetbrains_mins = EXCLUDED.jetbrains_mins, + app_usage_mins = EXCLUDED.app_usage_mins +WHERE + (tus.*) IS DISTINCT FROM (EXCLUDED.*); + -- name: GetTemplateParameterInsights :many -- GetTemplateParameterInsights does for each template in a given timeframe, -- look for the latest workspace build (for every workspace) that has been diff --git a/coderd/database/sqlc.yaml b/coderd/database/sqlc.yaml index 2884ff76b09985..7913a9acf1627e 100644 --- a/coderd/database/sqlc.yaml +++ b/coderd/database/sqlc.yaml @@ -48,6 +48,9 @@ sql: - column: "template_with_users.group_acl" go_type: type: "TemplateACL" + - column: "template_usage_stats.app_usage_mins" + go_type: + type: "StringMapOfInt" rename: template: TemplateTable template_with_user: Template diff --git a/coderd/database/types.go b/coderd/database/types.go index f21a3d46f50b74..2beb74c868a1f4 100644 --- a/coderd/database/types.go +++ b/coderd/database/types.go @@ -90,3 +90,25 @@ func (m *StringMap) Scan(src interface{}) error { func (m StringMap) Value() (driver.Value, error) { return json.Marshal(m) } + +type StringMapOfInt map[string]int64 + +func (m *StringMapOfInt) Scan(src interface{}) error { + if src == nil { + return nil + } + switch src := src.(type) { + case []byte: + err := json.Unmarshal(src, m) + if err != nil { + return err + } + default: + return xerrors.Errorf("unsupported Scan, storing driver.Value type %T into type %T", src, m) + } + return nil +} + +func (m StringMapOfInt) Value() (driver.Value, error) { + return json.Marshal(m) +} diff --git a/coderd/database/unique_constraint.go b/coderd/database/unique_constraint.go index 498fc24a8063e5..52de0a50f6a3e9 100644 --- a/coderd/database/unique_constraint.go +++ b/coderd/database/unique_constraint.go @@ -46,6 +46,7 @@ const ( UniqueTailnetCoordinatorsPkey UniqueConstraint = "tailnet_coordinators_pkey" // ALTER TABLE ONLY tailnet_coordinators ADD CONSTRAINT tailnet_coordinators_pkey PRIMARY KEY (id); UniqueTailnetPeersPkey UniqueConstraint = "tailnet_peers_pkey" // ALTER TABLE ONLY tailnet_peers ADD CONSTRAINT tailnet_peers_pkey PRIMARY KEY (id, coordinator_id); UniqueTailnetTunnelsPkey UniqueConstraint = "tailnet_tunnels_pkey" // ALTER TABLE ONLY tailnet_tunnels ADD CONSTRAINT tailnet_tunnels_pkey PRIMARY KEY (coordinator_id, src_id, dst_id); + UniqueTemplateUsageStatsPkey UniqueConstraint = "template_usage_stats_pkey" // ALTER TABLE ONLY template_usage_stats ADD CONSTRAINT template_usage_stats_pkey PRIMARY KEY (start_time, template_id, user_id); UniqueTemplateVersionParametersTemplateVersionIDNameKey UniqueConstraint = "template_version_parameters_template_version_id_name_key" // ALTER TABLE ONLY template_version_parameters ADD CONSTRAINT template_version_parameters_template_version_id_name_key UNIQUE (template_version_id, name); UniqueTemplateVersionVariablesTemplateVersionIDNameKey UniqueConstraint = "template_version_variables_template_version_id_name_key" // ALTER TABLE ONLY template_version_variables ADD CONSTRAINT template_version_variables_template_version_id_name_key UNIQUE (template_version_id, name); UniqueTemplateVersionsPkey UniqueConstraint = "template_versions_pkey" // ALTER TABLE ONLY template_versions ADD CONSTRAINT template_versions_pkey PRIMARY KEY (id); @@ -79,6 +80,7 @@ const ( UniqueIndexUsersEmail UniqueConstraint = "idx_users_email" // CREATE UNIQUE INDEX idx_users_email ON users USING btree (email) WHERE (deleted = false); UniqueIndexUsersUsername UniqueConstraint = "idx_users_username" // CREATE UNIQUE INDEX idx_users_username ON users USING btree (username) WHERE (deleted = false); UniqueOrganizationsSingleDefaultOrg UniqueConstraint = "organizations_single_default_org" // CREATE UNIQUE INDEX organizations_single_default_org ON organizations USING btree (is_default) WHERE (is_default = true); + UniqueTemplateUsageStatsStartTimeTemplateIDUserIDIndex UniqueConstraint = "template_usage_stats_start_time_template_id_user_id_idx" // CREATE UNIQUE INDEX template_usage_stats_start_time_template_id_user_id_idx ON template_usage_stats USING btree (start_time, template_id, user_id); UniqueTemplatesOrganizationIDNameIndex UniqueConstraint = "templates_organization_id_name_idx" // CREATE UNIQUE INDEX templates_organization_id_name_idx ON templates USING btree (organization_id, lower((name)::text)) WHERE (deleted = false); UniqueUsersEmailLowerIndex UniqueConstraint = "users_email_lower_idx" // CREATE UNIQUE INDEX users_email_lower_idx ON users USING btree (lower(email)) WHERE (deleted = false); UniqueUsersUsernameLowerIndex UniqueConstraint = "users_username_lower_idx" // CREATE UNIQUE INDEX users_username_lower_idx ON users USING btree (lower(username)) WHERE (deleted = false); From e626ab0243ab4f30e9e0cc56d374d0d651ed486a Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 13:20:26 +0000 Subject: [PATCH 02/19] fix: implement `UpsertTemplateUsageStats` in dbmem --- coderd/database/dbmem/dbmem.go | 576 ++++++++++++++++++++++++++++++++- 1 file changed, 573 insertions(+), 3 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index 30567f81fc89f8..bfccd2acd2c92f 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -7952,12 +7952,582 @@ func (*FakeQuerier) UpsertTailnetTunnel(_ context.Context, arg database.UpsertTa return database.TailnetTunnel{}, ErrUnimplemented } -func (q *FakeQuerier) UpsertTemplateUsageStats(_ context.Context) error { +func (q *FakeQuerier) UpsertTemplateUsageStats(ctx context.Context) error { q.mutex.Lock() defer q.mutex.Unlock() - // TODO(mafredri): Implement. - panic("not implemented") + /* + WITH + */ + + /* + latest_start AS ( + SELECT + COALESCE( + MAX(start_time) - '1 hour'::interval, + -- TODO(mafredri): Fix this, required for tests to pass. + NOW() - '2 years'::interval + ) AS t + FROM + template_usage_stats + ), + */ + + now := time.Now() + latestStart := now.AddDate(-2, 0, 0) + for _, stat := range q.templateUsageStats { + if stat.StartTime.After(latestStart) { + latestStart = stat.StartTime.Add(-time.Hour) + } + } + + /* + workspace_app_stat_buckets AS ( + SELECT + -- Truncate the minute to the nearest half hour, this is the bucket size + -- for the data. + date_trunc('hour', s.minute_bucket) + trunc(date_part('minute', s.minute_bucket) / 30) * 30 * '1 minute'::interval AS time_bucket, + w.template_id, + was.user_id, + -- Both app stats and agent stats track web terminal usage, but + -- by different means. The app stats value should be more + -- accurate so we don't want to discard it just yet. + CASE + WHEN was.access_method = 'terminal' + THEN '[terminal]' -- Unique name, app names can't contain brackets. + ELSE was.slug_or_port + END AS app_name, + COUNT(DISTINCT s.minute_bucket) AS app_minutes, + -- Store each unique minute bucket for later merge between datasets. + array_agg(DISTINCT s.minute_bucket) AS minute_buckets + FROM + workspace_app_stats AS was + JOIN + workspaces AS w + ON + w.id = was.workspace_id + -- Generate a series of minute buckets for each session for computing the + -- mintes/bucket. + CROSS JOIN + 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 + ) AS s(minute_bucket) + WHERE + -- s.minute_bucket >= @start_time::timestamptz + -- AND s.minute_bucket < @end_time::timestamptz + s.minute_bucket >= (SELECT t FROM latest_start) + AND s.minute_bucket < NOW() + GROUP BY + time_bucket, w.template_id, was.user_id, was.access_method, was.slug_or_port + ), + */ + + type workspaceAppStatGroupBy struct { + TimeBucket time.Time + TemplateID uuid.UUID + UserID uuid.UUID + AccessMethod string + SlugOrPort string + } + type workspaceAppStatRow struct { + workspaceAppStatGroupBy + AppName string + AppMinutes int + MinuteBuckets map[time.Time]struct{} + } + workspaceAppStatRows := make(map[workspaceAppStatGroupBy]workspaceAppStatRow) + for _, was := range q.workspaceAppStats { + // Preflight: s.minute_bucket >= (SELECT t FROM latest_start) + if was.SessionEndedAt.Before(latestStart) { + continue + } + // JOIN workspaces + w, err := q.getWorkspaceByIDNoLock(ctx, was.WorkspaceID) + if err != nil { + return err + } + // CROSS JOIN generate_series + for t := was.SessionStartedAt; t.Before(was.SessionEndedAt); t = t.Add(time.Minute) { + // WHERE + if t.Before(latestStart) || t.After(now) || t.Equal(now) { + continue + } + + bucket := t.Truncate(30 * time.Minute) + // GROUP BY + key := workspaceAppStatGroupBy{ + TimeBucket: bucket, + TemplateID: w.TemplateID, + UserID: was.UserID, + AccessMethod: was.AccessMethod, + SlugOrPort: was.SlugOrPort, + } + // SELECT + row, ok := workspaceAppStatRows[key] + if !ok { + row = workspaceAppStatRow{ + workspaceAppStatGroupBy: key, + AppName: was.SlugOrPort, + AppMinutes: 0, + MinuteBuckets: make(map[time.Time]struct{}), + } + if was.AccessMethod == "terminal" { + row.AppName = "[terminal]" + } + } + row.MinuteBuckets[t] = struct{}{} + row.AppMinutes = len(row.MinuteBuckets) + workspaceAppStatRows[key] = row + } + } + + /* + agent_stats_buckets AS ( + SELECT + -- Truncate the minute to the nearest half hour, this is the bucket size + -- for the data. + date_trunc('hour', created_at) + trunc(date_part('minute', created_at) / 30) * 30 * '1 minute'::interval AS time_bucket, + template_id, + user_id, + -- Store each unique minute bucket for later merge between datasets. + array_agg( + DISTINCT CASE + WHEN + session_count_ssh > 0 + -- TODO(mafredri): Enable when we have the column. + -- OR session_count_sftp > 0 + OR session_count_reconnecting_pty > 0 + OR session_count_vscode > 0 + OR session_count_jetbrains > 0 + THEN + date_trunc('minute', created_at) + ELSE + NULL + END + ) AS minute_buckets, + COUNT(DISTINCT CASE WHEN session_count_ssh > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS ssh_mins, + -- TODO(mafredri): Enable when we have the column. + -- COUNT(DISTINCT CASE WHEN session_count_sftp > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS sftp_mins, + COUNT(DISTINCT CASE WHEN session_count_reconnecting_pty > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS reconnecting_pty_mins, + COUNT(DISTINCT CASE WHEN session_count_vscode > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS vscode_mins, + COUNT(DISTINCT CASE WHEN session_count_jetbrains > 0 THEN date_trunc('minute', created_at) ELSE NULL END) AS jetbrains_mins, + -- NOTE(mafredri): The agent stats are currently very unreliable, and + -- sometimes the connections are missing, even during active sessions. + -- Since we can't fully rely on this, we check for "any connection + -- during this half-hour". A better solution here would be preferable. + MAX(connection_count) > 0 AS has_connection + FROM + workspace_agent_stats + WHERE + -- created_at >= @start_time::timestamptz + -- AND created_at < @end_time::timestamptz + created_at >= (SELECT t FROM latest_start) + AND created_at < NOW() + -- Inclusion criteria to filter out empty results. + AND ( + session_count_ssh > 0 + -- TODO(mafredri): Enable when we have the column. + -- OR session_count_sftp > 0 + OR session_count_reconnecting_pty > 0 + OR session_count_vscode > 0 + OR session_count_jetbrains > 0 + ) + GROUP BY + time_bucket, template_id, user_id + ), + */ + + type agentStatGroupBy struct { + TimeBucket time.Time + TemplateID uuid.UUID + UserID uuid.UUID + } + type agentStatRow struct { + agentStatGroupBy + MinuteBuckets map[time.Time]struct{} + SSHMinuteBuckets map[time.Time]struct{} + SSHMins int + SFTPMinuteBuckets map[time.Time]struct{} + SFTPMins int + ReconnectingPTYMinuteBuckets map[time.Time]struct{} + ReconnectingPTYMins int + VSCodeMinuteBuckets map[time.Time]struct{} + VSCodeMins int + JetBrainsMinuteBuckets map[time.Time]struct{} + JetBrainsMins int + HasConnection bool + } + agentStatRows := make(map[agentStatGroupBy]agentStatRow) + for _, was := range q.workspaceAgentStats { + // WHERE + if was.CreatedAt.Before(latestStart) || was.CreatedAt.After(now) || was.CreatedAt.Equal(now) { + continue + } + if was.SessionCountSSH == 0 && was.SessionCountReconnectingPTY == 0 && was.SessionCountVSCode == 0 && was.SessionCountJetBrains == 0 { + continue + } + // GROUP BY + key := agentStatGroupBy{ + TimeBucket: was.CreatedAt.Truncate(30 * time.Minute), + TemplateID: was.TemplateID, + UserID: was.UserID, + } + // SELECT + row, ok := agentStatRows[key] + if !ok { + row = agentStatRow{ + agentStatGroupBy: key, + MinuteBuckets: make(map[time.Time]struct{}), + SSHMinuteBuckets: make(map[time.Time]struct{}), + SFTPMinuteBuckets: make(map[time.Time]struct{}), + ReconnectingPTYMinuteBuckets: make(map[time.Time]struct{}), + VSCodeMinuteBuckets: make(map[time.Time]struct{}), + JetBrainsMinuteBuckets: make(map[time.Time]struct{}), + } + } + minute := was.CreatedAt.Truncate(time.Minute) + row.MinuteBuckets[minute] = struct{}{} + if was.SessionCountSSH > 0 { + row.SSHMinuteBuckets[minute] = struct{}{} + row.SSHMins = len(row.SSHMinuteBuckets) + } + // TODO(mafredri): Enable when we have the column. + // if was.SessionCountSFTP > 0 { + // row.SFTPMinuteBuckets[minute] = struct{}{} + // row.SFTPMins = len(row.SFTPMinuteBuckets) + // } + _ = row.SFTPMinuteBuckets + if was.SessionCountReconnectingPTY > 0 { + row.ReconnectingPTYMinuteBuckets[minute] = struct{}{} + row.ReconnectingPTYMins = len(row.ReconnectingPTYMinuteBuckets) + } + if was.SessionCountVSCode > 0 { + row.VSCodeMinuteBuckets[minute] = struct{}{} + row.VSCodeMins = len(row.VSCodeMinuteBuckets) + } + if was.SessionCountJetBrains > 0 { + row.JetBrainsMinuteBuckets[minute] = struct{}{} + row.JetBrainsMins = len(row.JetBrainsMinuteBuckets) + } + if !row.HasConnection { + row.HasConnection = was.ConnectionCount > 0 + } + agentStatRows[key] = row + } + + /* + stats AS ( + SELECT + stats.time_bucket AS start_time, + stats.time_bucket + '30 minutes'::interval AS end_time, + stats.template_id, + stats.user_id, + -- Sum/distinct to handle zero/duplicate values due union and to unnest. + COUNT(DISTINCT minute_bucket) AS usage_mins, + array_agg(DISTINCT minute_bucket) AS minute_buckets, + SUM(DISTINCT stats.ssh_mins) AS ssh_mins, + SUM(DISTINCT stats.sftp_mins) AS sftp_mins, + SUM(DISTINCT stats.reconnecting_pty_mins) AS reconnecting_pty_mins, + SUM(DISTINCT stats.vscode_mins) AS vscode_mins, + SUM(DISTINCT stats.jetbrains_mins) AS jetbrains_mins, + -- This is what we unnested, re-nest as json. + jsonb_object_agg(stats.app_name, stats.app_minutes) FILTER (WHERE stats.app_name IS NOT NULL) AS app_usage_mins + FROM ( + SELECT + time_bucket, + template_id, + user_id, + 0 AS ssh_mins, + 0 AS sftp_mins, + 0 AS reconnecting_pty_mins, + 0 AS vscode_mins, + 0 AS jetbrains_mins, + app_name, + app_minutes, + minute_buckets + FROM + workspace_app_stat_buckets + + UNION ALL + + SELECT + time_bucket, + template_id, + user_id, + ssh_mins, + -- TODO(mafredri): Enable when we have the column. + 0 AS sftp_mins, + reconnecting_pty_mins, + vscode_mins, + jetbrains_mins, + NULL AS app_name, + NULL AS app_minutes, + minute_buckets + FROM + agent_stats_buckets + WHERE + -- See note in the agent_stats_buckets CTE. + has_connection + ) AS stats, unnest(minute_buckets) AS minute_bucket + GROUP BY + stats.time_bucket, stats.template_id, stats.user_id + ), + */ + + type statsGroupBy struct { + TimeBucket time.Time + TemplateID uuid.UUID + UserID uuid.UUID + } + type statsRow struct { + statsGroupBy + UsageMinuteBuckets map[time.Time]struct{} + UsageMins int + SSHMins int + SFTPMins int + ReconnectingPTYMins int + VSCodeMins int + JetBrainsMins int + AppUsageMinutes map[string]int + } + statsRows := make(map[statsGroupBy]statsRow) + for _, was := range workspaceAppStatRows { + // GROUP BY + key := statsGroupBy{ + TimeBucket: was.TimeBucket, + TemplateID: was.TemplateID, + UserID: was.UserID, + } + // SELECT + row, ok := statsRows[key] + if !ok { + row = statsRow{ + statsGroupBy: key, + UsageMinuteBuckets: make(map[time.Time]struct{}), + AppUsageMinutes: make(map[string]int), + } + } + for t := range was.MinuteBuckets { + row.UsageMinuteBuckets[t] = struct{}{} + } + row.UsageMins = len(row.UsageMinuteBuckets) + row.AppUsageMinutes[was.AppName] = was.AppMinutes + statsRows[key] = row + } + for _, was := range agentStatRows { + // GROUP BY + key := statsGroupBy{ + TimeBucket: was.TimeBucket, + TemplateID: was.TemplateID, + UserID: was.UserID, + } + // SELECT + row, ok := statsRows[key] + if !ok { + row = statsRow{ + statsGroupBy: key, + UsageMinuteBuckets: make(map[time.Time]struct{}), + AppUsageMinutes: make(map[string]int), + } + } + for t := range was.MinuteBuckets { + row.UsageMinuteBuckets[t] = struct{}{} + } + row.UsageMins = len(row.UsageMinuteBuckets) + row.SSHMins += was.SSHMins + row.SFTPMins += was.SFTPMins + row.ReconnectingPTYMins += was.ReconnectingPTYMins + row.VSCodeMins += was.VSCodeMins + row.JetBrainsMins += was.JetBrainsMins + statsRows[key] = row + } + + /* + minute_buckets AS ( + -- Create distinct minute buckets for user-activity, so we can filter out + -- irrelevant latencies. + SELECT DISTINCT ON (stats.start_time, stats.template_id, stats.user_id, minute_bucket) + stats.start_time, + stats.template_id, + stats.user_id, + minute_bucket + FROM + stats, unnest(minute_buckets) AS minute_bucket + ), + latencies AS ( + -- Select all non-zero latencies for all the minutes that a user used the + -- workspace in some way. + SELECT + mb.start_time, + mb.template_id, + mb.user_id, + -- TODO(mafredri): We're doing medians on medians here, we may want to + -- improve upon this at some point. + PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY was.connection_median_latency_ms)::real AS median_latency_ms + FROM + minute_buckets AS mb + JOIN + workspace_agent_stats AS was + ON + date_trunc('minute', was.created_at) = mb.minute_bucket + AND was.template_id = mb.template_id + AND was.user_id = mb.user_id + AND was.connection_median_latency_ms >= 0 + GROUP BY + mb.start_time, mb.template_id, mb.user_id + ) + */ + + type latenciesGroupBy struct { + StartTime time.Time + TemplateID uuid.UUID + UserID uuid.UUID + } + type latenciesRow struct { + latenciesGroupBy + Latencies []float64 + MedianLatencyMS float64 + } + latenciesRows := make(map[latenciesGroupBy]latenciesRow) + for _, stat := range statsRows { + for t := range stat.UsageMinuteBuckets { + // GROUP BY + key := latenciesGroupBy{ + StartTime: stat.TimeBucket, + TemplateID: stat.TemplateID, + UserID: stat.UserID, + } + // JOIN + for _, was := range q.workspaceAgentStats { + if !t.Equal(was.CreatedAt.Truncate(time.Minute)) { + continue + } + if was.TemplateID != stat.TemplateID || was.UserID != stat.UserID { + continue + } + if was.ConnectionMedianLatencyMS < 0 { + continue + } + // SELECT + row, ok := latenciesRows[key] + if !ok { + row = latenciesRow{ + latenciesGroupBy: key, + } + } + row.Latencies = append(row.Latencies, was.ConnectionMedianLatencyMS) + sort.Float64s(row.Latencies) + if len(row.Latencies) == 1 { + row.MedianLatencyMS = was.ConnectionMedianLatencyMS + } else if len(row.Latencies)%2 == 0 { + row.MedianLatencyMS = (row.Latencies[len(row.Latencies)/2-1] + row.Latencies[len(row.Latencies)/2]) / 2 + } else { + row.MedianLatencyMS = row.Latencies[len(row.Latencies)/2] + } + latenciesRows[key] = row + } + } + } + + /* + INSERT INTO template_usage_stats AS tus ( + start_time, + end_time, + template_id, + user_id, + usage_mins, + median_latency_ms, + ssh_mins, + sftp_mins, + reconnecting_pty_mins, + vscode_mins, + jetbrains_mins, + app_usage_mins + ) ( + SELECT + stats.start_time, + stats.end_time, + stats.template_id, + stats.user_id, + stats.usage_mins, + latencies.median_latency_ms, + stats.ssh_mins, + stats.sftp_mins, + stats.reconnecting_pty_mins, + stats.vscode_mins, + stats.jetbrains_mins, + stats.app_usage_mins + FROM + stats + LEFT JOIN + latencies + ON + -- The latencies group-by ensures there at most one row. + latencies.start_time = stats.start_time + AND latencies.template_id = stats.template_id + AND latencies.user_id = stats.user_id + ) + ON CONFLICT + (start_time, template_id, user_id) + DO UPDATE + SET + usage_mins = EXCLUDED.usage_mins, + median_latency_ms = EXCLUDED.median_latency_ms, + ssh_mins = EXCLUDED.ssh_mins, + sftp_mins = EXCLUDED.sftp_mins, + reconnecting_pty_mins = EXCLUDED.reconnecting_pty_mins, + vscode_mins = EXCLUDED.vscode_mins, + jetbrains_mins = EXCLUDED.jetbrains_mins, + app_usage_mins = EXCLUDED.app_usage_mins + WHERE + (tus.*) IS DISTINCT FROM (EXCLUDED.*); + */ + +TemplateUsageStatsInsertLoop: + for _, stat := range statsRows { + // LEFT JOIN latencies + latency, latencyOk := latenciesRows[latenciesGroupBy{ + StartTime: stat.TimeBucket, + TemplateID: stat.TemplateID, + UserID: stat.UserID, + }] + + // SELECT + tus := database.TemplateUsageStat{ + StartTime: stat.TimeBucket, + EndTime: stat.TimeBucket.Add(30 * time.Minute), + TemplateID: stat.TemplateID, + UserID: stat.UserID, + UsageMins: int16(stat.UsageMins), + MedianLatencyMs: sql.NullFloat64{Float64: latency.MedianLatencyMS, Valid: latencyOk}, + SshMins: int16(stat.SSHMins), + SftpMins: int16(stat.SFTPMins), + ReconnectingPtyMins: int16(stat.ReconnectingPTYMins), + VscodeMins: int16(stat.VSCodeMins), + JetbrainsMins: int16(stat.JetBrainsMins), + } + if len(stat.AppUsageMinutes) > 0 { + tus.AppUsageMins = make(map[string]int64, len(stat.AppUsageMinutes)) + for k, v := range stat.AppUsageMinutes { + tus.AppUsageMins[k] = int64(v) + } + } + + // ON CONFLICT + for i, existing := range q.templateUsageStats { + if existing.StartTime.Equal(tus.StartTime) && existing.TemplateID == tus.TemplateID && existing.UserID == tus.UserID { + q.templateUsageStats[i] = tus + continue TemplateUsageStatsInsertLoop + } + } + // INSERT INTO + q.templateUsageStats = append(q.templateUsageStats, tus) + } + + return nil } func (q *FakeQuerier) UpsertWorkspaceAgentPortShare(_ context.Context, arg database.UpsertWorkspaceAgentPortShareParams) (database.WorkspaceAgentPortShare, error) { From 803de96f35c4a748848553765f8f4d42f67f2e19 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 14:52:39 +0000 Subject: [PATCH 03/19] fix gen --- coderd/database/dump.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/coderd/database/dump.sql b/coderd/database/dump.sql index 7159edc279233e..da2707b5895bee 100644 --- a/coderd/database/dump.sql +++ b/coderd/database/dump.sql @@ -1847,3 +1847,4 @@ ALTER TABLE ONLY workspaces ALTER TABLE ONLY workspaces ADD CONSTRAINT workspaces_template_id_fkey FOREIGN KEY (template_id) REFERENCES templates(id) ON DELETE RESTRICT; + From 385e01929909bfe8460a1f302b099e5a41cf9417 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 16:01:46 +0000 Subject: [PATCH 04/19] fix dbauthz --- coderd/database/dbauthz/dbauthz_test.go | 6 ++++++ ..._stats.down.sql => 000203_template_usage_stats.down.sql} | 0 ...sage_stats.up.sql => 000203_template_usage_stats.up.sql} | 0 3 files changed, 6 insertions(+) rename coderd/database/migrations/{000202_template_usage_stats.down.sql => 000203_template_usage_stats.down.sql} (100%) rename coderd/database/migrations/{000202_template_usage_stats.up.sql => 000203_template_usage_stats.up.sql} (100%) diff --git a/coderd/database/dbauthz/dbauthz_test.go b/coderd/database/dbauthz/dbauthz_test.go index 8840fe55250454..19f970d2afb111 100644 --- a/coderd/database/dbauthz/dbauthz_test.go +++ b/coderd/database/dbauthz/dbauthz_test.go @@ -956,6 +956,12 @@ func (s *MethodTestSuite) TestTemplate() { s.Run("GetTemplateAppInsightsByTemplate", s.Subtest(func(db database.Store, check *expects) { check.Args(database.GetTemplateAppInsightsByTemplateParams{}).Asserts(rbac.ResourceTemplateInsights, rbac.ActionRead) })) + s.Run("GetTemplateUsageStats", s.Subtest(func(db database.Store, check *expects) { + check.Args(database.GetTemplateUsageStatsParams{}).Asserts(rbac.ResourceTemplateInsights, rbac.ActionRead).Errors(sql.ErrNoRows) + })) + s.Run("UpsertTemplateUsageStats", s.Subtest(func(db database.Store, check *expects) { + check.Asserts(rbac.ResourceSystem, rbac.ActionUpdate) + })) } func (s *MethodTestSuite) TestUser() { diff --git a/coderd/database/migrations/000202_template_usage_stats.down.sql b/coderd/database/migrations/000203_template_usage_stats.down.sql similarity index 100% rename from coderd/database/migrations/000202_template_usage_stats.down.sql rename to coderd/database/migrations/000203_template_usage_stats.down.sql diff --git a/coderd/database/migrations/000202_template_usage_stats.up.sql b/coderd/database/migrations/000203_template_usage_stats.up.sql similarity index 100% rename from coderd/database/migrations/000202_template_usage_stats.up.sql rename to coderd/database/migrations/000203_template_usage_stats.up.sql From 310f54518b607c16be5140375daf3ff2d6620357 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 19:17:54 +0000 Subject: [PATCH 05/19] add fixture --- .../000203_template_usage_stats.up.sql | 30 +++++++++++++++++++ 1 file changed, 30 insertions(+) create mode 100644 coderd/database/migrations/testdata/fixtures/000203_template_usage_stats.up.sql diff --git a/coderd/database/migrations/testdata/fixtures/000203_template_usage_stats.up.sql b/coderd/database/migrations/testdata/fixtures/000203_template_usage_stats.up.sql new file mode 100644 index 00000000000000..38b273f89e7659 --- /dev/null +++ b/coderd/database/migrations/testdata/fixtures/000203_template_usage_stats.up.sql @@ -0,0 +1,30 @@ +INSERT INTO + template_usage_stats ( + start_time, + end_time, + template_id, + user_id, + median_latency_ms, + usage_mins, + ssh_mins, + sftp_mins, + reconnecting_pty_mins, + vscode_mins, + jetbrains_mins, + app_usage_mins + ) +VALUES + ( + date_trunc('hour', NOW()), + date_trunc('hour', NOW()) + '30 minute'::interval, + gen_random_uuid(), + gen_random_uuid(), + 45.342::real, + 30, -- usage + 30, -- ssh + 5, -- sftp + 2, -- reconnecting_pty + 10, -- vscode + 10, -- jetbrains + '{"[terminal]": 2, "code-server": 30}'::jsonb + ); From 71451897f1509c5f7b9e2ff3ebb62f2450cad942 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Mon, 18 Mar 2024 20:27:21 +0200 Subject: [PATCH 06/19] feat(coderd/database): add `dbrollup` service to rollup insights --- coderd/coderd.go | 18 ++- coderd/coderdtest/coderdtest.go | 2 + coderd/database/dbgen/dbgen.go | 32 +++++ coderd/database/dbpurge/dbpurge.go | 1 + coderd/database/dbrollup/dbrollup.go | 130 +++++++++++++++++ coderd/database/dbrollup/dbrollup_test.go | 167 ++++++++++++++++++++++ coderd/database/lock.go | 5 +- 7 files changed, 350 insertions(+), 5 deletions(-) create mode 100644 coderd/database/dbrollup/dbrollup.go create mode 100644 coderd/database/dbrollup/dbrollup_test.go diff --git a/coderd/coderd.go b/coderd/coderd.go index 264901b811435a..bc0641b2e85ddb 100644 --- a/coderd/coderd.go +++ b/coderd/coderd.go @@ -47,6 +47,7 @@ import ( "github.com/coder/coder/v2/coderd/batchstats" "github.com/coder/coder/v2/coderd/database" "github.com/coder/coder/v2/coderd/database/dbauthz" + "github.com/coder/coder/v2/coderd/database/dbrollup" "github.com/coder/coder/v2/coderd/database/dbtime" "github.com/coder/coder/v2/coderd/database/pubsub" "github.com/coder/coder/v2/coderd/externalauth" @@ -180,6 +181,7 @@ type Options struct { UpdateAgentMetrics func(ctx context.Context, labels prometheusmetrics.AgentMetricLabels, metrics []*agentproto.Stats_Metric) StatsBatcher *batchstats.Batcher + DBRollupInterval time.Duration WorkspaceAppsStatsCollectorOptions workspaceapps.StatsCollectorOptions @@ -342,6 +344,9 @@ func New(options *Options) *API { if options.StatsBatcher == nil { panic("developer error: options.StatsBatcher is nil") } + if options.DBRollupInterval == 0 { + options.DBRollupInterval = dbrollup.DefaultInterval + } siteCacheDir := options.CacheDir if siteCacheDir != "" { @@ -414,7 +419,13 @@ func New(options *Options) *API { ctx, options.Logger.Named("acquirer"), options.Database, - options.Pubsub), + options.Pubsub, + ), + rolluper: dbrollup.New( + options.Logger, + options.Database, + options.DBRollupInterval, + ), workspaceUsageTracker: options.WorkspaceUsageTracker, } @@ -1190,7 +1201,9 @@ type API struct { statsBatcher *batchstats.Batcher Acquirer *provisionerdserver.Acquirer - + // rolluper rolls up template usage stats from raw agent and app + // stats. This is used to provide insights in the WebUI. + rolluper *dbrollup.Rolluper workspaceUsageTracker *workspaceusage.Tracker } @@ -1203,6 +1216,7 @@ func (api *API) Close() error { api.WebsocketWaitGroup.Wait() api.WebsocketWaitMutex.Unlock() + api.rolluper.Close() api.metricsCache.Close() if api.updateChecker != nil { api.updateChecker.Close() diff --git a/coderd/coderdtest/coderdtest.go b/coderd/coderdtest/coderdtest.go index 303f840938817f..3606dc362fc114 100644 --- a/coderd/coderdtest/coderdtest.go +++ b/coderd/coderdtest/coderdtest.go @@ -147,6 +147,7 @@ type Options struct { WorkspaceAppsStatsCollectorOptions workspaceapps.StatsCollectorOptions AllowWorkspaceRenames bool NewTicker func(duration time.Duration) (<-chan time.Time, func()) + DBRollupInterval time.Duration WorkspaceUsageTrackerFlush chan int WorkspaceUsageTrackerTick chan time.Time } @@ -487,6 +488,7 @@ func NewOptions(t testing.TB, options *Options) (func(http.Handler), context.Can WorkspaceAppsStatsCollectorOptions: options.WorkspaceAppsStatsCollectorOptions, AllowWorkspaceRenames: options.AllowWorkspaceRenames, NewTicker: options.NewTicker, + DBRollupInterval: options.DBRollupInterval, WorkspaceUsageTracker: wuTracker, } } diff --git a/coderd/database/dbgen/dbgen.go b/coderd/database/dbgen/dbgen.go index da5f214e7f3140..707e977178cde8 100644 --- a/coderd/database/dbgen/dbgen.go +++ b/coderd/database/dbgen/dbgen.go @@ -489,6 +489,38 @@ func WorkspaceApp(t testing.TB, db database.Store, orig database.WorkspaceApp) d return resource } +func WorkspaceAppStat(t testing.TB, db database.Store, orig database.WorkspaceAppStat) database.WorkspaceAppStat { + // This is not going to be correct, but our query doesn't return the ID. + id, err := cryptorand.Int63() + require.NoError(t, err, "generate id") + + scheme := database.WorkspaceAppStat{ + ID: takeFirst(orig.ID, id), + UserID: takeFirst(orig.UserID, uuid.New()), + WorkspaceID: takeFirst(orig.WorkspaceID, uuid.New()), + AgentID: takeFirst(orig.AgentID, uuid.New()), + AccessMethod: takeFirst(orig.AccessMethod, ""), + SlugOrPort: takeFirst(orig.SlugOrPort, ""), + SessionID: takeFirst(orig.SessionID, uuid.New()), + SessionStartedAt: takeFirst(orig.SessionStartedAt, dbtime.Now().Add(-time.Minute)), + SessionEndedAt: takeFirst(orig.SessionEndedAt, dbtime.Now()), + Requests: takeFirst(orig.Requests, 1), + } + err = db.InsertWorkspaceAppStats(genCtx, database.InsertWorkspaceAppStatsParams{ + UserID: []uuid.UUID{scheme.UserID}, + WorkspaceID: []uuid.UUID{scheme.WorkspaceID}, + AgentID: []uuid.UUID{scheme.AgentID}, + AccessMethod: []string{scheme.AccessMethod}, + SlugOrPort: []string{scheme.SlugOrPort}, + SessionID: []uuid.UUID{scheme.SessionID}, + SessionStartedAt: []time.Time{scheme.SessionStartedAt}, + SessionEndedAt: []time.Time{scheme.SessionEndedAt}, + Requests: []int32{scheme.Requests}, + }) + require.NoError(t, err, "insert workspace agent stat") + return scheme +} + func WorkspaceResource(t testing.TB, db database.Store, orig database.WorkspaceResource) database.WorkspaceResource { resource, err := db.InsertWorkspaceResource(genCtx, database.InsertWorkspaceResourceParams{ ID: takeFirst(orig.ID, uuid.New()), diff --git a/coderd/database/dbpurge/dbpurge.go b/coderd/database/dbpurge/dbpurge.go index d3fc56a8c5f217..c4b5a609a31792 100644 --- a/coderd/database/dbpurge/dbpurge.go +++ b/coderd/database/dbpurge/dbpurge.go @@ -24,6 +24,7 @@ const ( // This is for cleaning up old, unused resources from the database that take up space. func New(ctx context.Context, logger slog.Logger, db database.Store) io.Closer { closed := make(chan struct{}) + logger = logger.Named("dbpurge") ctx, cancelFunc := context.WithCancel(ctx) //nolint:gocritic // The system purges old db records without user input. diff --git a/coderd/database/dbrollup/dbrollup.go b/coderd/database/dbrollup/dbrollup.go new file mode 100644 index 00000000000000..55eaaf171aa84f --- /dev/null +++ b/coderd/database/dbrollup/dbrollup.go @@ -0,0 +1,130 @@ +package dbrollup + +import ( + "context" + "time" + + "golang.org/x/sync/errgroup" + + "cdr.dev/slog" + + "github.com/coder/coder/v2/coderd/database" + "github.com/coder/coder/v2/coderd/database/dbauthz" +) + +const ( + // DefaultInterval is the default time between rollups. + // Rollups will be synchronized with the clock so that + // they happen 13:00, 13:05, 13:10, etc. + DefaultInterval = 5 * time.Minute +) + +type Rolluper struct { + cancel context.CancelFunc + closed chan struct{} + db database.Store + logger slog.Logger +} + +// New creates a new DB rollup service that periodically runs rollup queries. +// It is the caller's responsibility to call Close on the returned instance. +// +// This is for e.g. generating insights data (template_usage_stats) from +// raw data (workspace_agent_stats, workspace_app_stats). +func New(logger slog.Logger, db database.Store, interval time.Duration) *Rolluper { + ctx, cancel := context.WithCancel(context.Background()) + + r := &Rolluper{ + cancel: cancel, + closed: make(chan struct{}), + db: db, + logger: logger.Named("dbrollup"), + } + + //nolint:gocritic // The system rolls up database tables without user input. + ctx = dbauthz.AsSystemRestricted(ctx) + go r.start(ctx, interval) + + return r +} + +func (r *Rolluper) start(ctx context.Context, interval time.Duration) { + defer close(r.closed) + + do := func() { + var eg errgroup.Group + + r.logger.Debug(ctx, "rolling up data") + now := time.Now() + + // Track whether or not we performed a rollup (we got the advisory lock). + templateUsageStats := false + + eg.Go(func() error { + return r.db.InTx(func(tx database.Store) error { + // Acquire a lock to ensure that only one instance of + // the rollup is running at a time. + ok, err := tx.TryAcquireLock(ctx, database.LockIDDBRollup) + if err != nil { + return err + } + if !ok { + return nil + } + + templateUsageStats = true + return tx.UpsertTemplateUsageStats(ctx) + }, nil) + }) + + err := eg.Wait() + if err != nil { + if database.IsQueryCanceledError(err) { + return + } + // Only log if Close hasn't been called. + if ctx.Err() == nil { + r.logger.Error(ctx, "failed to rollup data", slog.Error(err)) + } + } else { + r.logger.Debug(ctx, + "rolled up data", + slog.F("took", time.Since(now)), + slog.F("template_usage_stats", templateUsageStats), + ) + } + } + + // Perform do immediately and on every tick of the ticker, + // disregarding the execution time of do. This ensure that + // the rollup is performed every interval assuming do does + // not take longer than the interval to execute. + t := time.NewTicker(time.Microsecond) + defer t.Stop() + for { + select { + case <-ctx.Done(): + return + case <-t.C: + // Ensure we're on the interval. + now := time.Now() + next := now.Add(interval).Truncate(interval) // Ensure we're on the interval and synced with the clock. + d := next.Sub(now) + // Safety check (shouldn't be possible). + if d <= 0 { + d = interval + } + t.Reset(d) + + do() + + r.logger.Debug(ctx, "next rollup at", slog.F("next", next)) + } + } +} + +func (r *Rolluper) Close() error { + r.cancel() + <-r.closed + return nil +} diff --git a/coderd/database/dbrollup/dbrollup_test.go b/coderd/database/dbrollup/dbrollup_test.go new file mode 100644 index 00000000000000..57909b774b77e4 --- /dev/null +++ b/coderd/database/dbrollup/dbrollup_test.go @@ -0,0 +1,167 @@ +package dbrollup_test + +import ( + "context" + "database/sql" + "errors" + "testing" + "time" + + "github.com/google/uuid" + "github.com/stretchr/testify/require" + "go.uber.org/goleak" + + "cdr.dev/slog" + "cdr.dev/slog/sloggers/slogtest" + + "github.com/coder/coder/v2/coderd/database" + "github.com/coder/coder/v2/coderd/database/dbgen" + "github.com/coder/coder/v2/coderd/database/dbmem" + "github.com/coder/coder/v2/coderd/database/dbrollup" + "github.com/coder/coder/v2/coderd/database/dbtestutil" + "github.com/coder/coder/v2/coderd/database/dbtime" + "github.com/coder/coder/v2/testutil" +) + +func TestMain(m *testing.M) { + goleak.VerifyTestMain(m) +} + +func TestRollup_Close(t *testing.T) { + t.Parallel() + rolluper := dbrollup.New(slogtest.Make(t, nil), dbmem.New(), dbrollup.DefaultInterval) + err := rolluper.Close() + require.NoError(t, err) +} + +func TestRollupTemplateUsageStats(t *testing.T) { + t.Parallel() + + db, ps := dbtestutil.NewDB(t, dbtestutil.WithDumpOnFailure()) + logger := slogtest.Make(t, &slogtest.Options{IgnoreErrors: true}).Leveled(slog.LevelDebug) + + anHourAgo := dbtime.Now().Add(-time.Hour).Truncate(time.Hour) + anHourAndSixMonthsAgo := anHourAgo.AddDate(0, -6, 0) + + org := dbgen.Organization(t, db, database.Organization{}) + user := dbgen.User(t, db, database.User{Name: "user1"}) + tpl := dbgen.Template(t, db, database.Template{OrganizationID: org.ID, CreatedBy: user.ID}) + ver := dbgen.TemplateVersion(t, db, database.TemplateVersion{ + OrganizationID: org.ID, + TemplateID: uuid.NullUUID{UUID: tpl.ID, Valid: true}, + CreatedBy: user.ID, + }) + ws := dbgen.Workspace(t, db, database.Workspace{ + OrganizationID: org.ID, + TemplateID: tpl.ID, OwnerID: user.ID, + }) + job := dbgen.ProvisionerJob(t, db, ps, database.ProvisionerJob{OrganizationID: org.ID}) + build := dbgen.WorkspaceBuild(t, db, database.WorkspaceBuild{ + WorkspaceID: ws.ID, + JobID: job.ID, + TemplateVersionID: ver.ID, + }) + res := dbgen.WorkspaceResource(t, db, database.WorkspaceResource{JobID: build.JobID}) + agent := dbgen.WorkspaceAgent(t, db, database.WorkspaceAgent{ResourceID: res.ID}) + app := dbgen.WorkspaceApp(t, db, database.WorkspaceApp{AgentID: agent.ID}) + + // Stats inserted 6 months + 1 day ago, should be excluded. + _ = dbgen.WorkspaceAgentStat(t, db, database.WorkspaceAgentStat{ + TemplateID: tpl.ID, + WorkspaceID: ws.ID, + AgentID: agent.ID, + UserID: user.ID, + CreatedAt: anHourAndSixMonthsAgo.AddDate(0, 0, -1), + ConnectionMedianLatencyMS: 1, + ConnectionCount: 1, + SessionCountSSH: 1, + }) + _ = dbgen.WorkspaceAppStat(t, db, database.WorkspaceAppStat{ + UserID: user.ID, + WorkspaceID: ws.ID, + AgentID: agent.ID, + SessionStartedAt: anHourAndSixMonthsAgo.AddDate(0, 0, -1), + SessionEndedAt: anHourAndSixMonthsAgo.AddDate(0, 0, -1).Add(time.Minute), + SlugOrPort: app.Slug, + }) + + // Stats inserted 6 months - 1 day ago, should be rolled up. + wags1 := dbgen.WorkspaceAgentStat(t, db, database.WorkspaceAgentStat{ + TemplateID: tpl.ID, + WorkspaceID: ws.ID, + AgentID: agent.ID, + UserID: user.ID, + CreatedAt: anHourAndSixMonthsAgo.AddDate(0, 0, 1), + ConnectionMedianLatencyMS: 1, + ConnectionCount: 1, + SessionCountReconnectingPTY: 1, + }) + wags2 := dbgen.WorkspaceAgentStat(t, db, database.WorkspaceAgentStat{ + TemplateID: tpl.ID, + WorkspaceID: ws.ID, + AgentID: agent.ID, + UserID: user.ID, + CreatedAt: wags1.CreatedAt.Add(time.Minute), + ConnectionMedianLatencyMS: 1, + ConnectionCount: 1, + SessionCountReconnectingPTY: 1, + }) + // wags2 and waps1 overlap, so total usage is 4 - 1. + waps1 := dbgen.WorkspaceAppStat(t, db, database.WorkspaceAppStat{ + UserID: user.ID, + WorkspaceID: ws.ID, + AgentID: agent.ID, + SessionStartedAt: wags2.CreatedAt, + SessionEndedAt: wags2.CreatedAt.Add(time.Minute), + SlugOrPort: app.Slug, + }) + waps2 := dbgen.WorkspaceAppStat(t, db, database.WorkspaceAppStat{ + UserID: user.ID, + WorkspaceID: ws.ID, + AgentID: agent.ID, + SessionStartedAt: waps1.SessionEndedAt, + SessionEndedAt: waps1.SessionEndedAt.Add(time.Minute), + SlugOrPort: app.Slug, + }) + _ = waps2 // Keep the name for documentation. + + // The data is already present, so we can rely on initial rollup to occur. + rolluper := dbrollup.New(logger, db, dbrollup.DefaultInterval) + defer rolluper.Close() + + ctx, cancel := context.WithTimeout(context.Background(), testutil.WaitShort) + defer cancel() + testutil.Go(t, func() { + <-ctx.Done() + _ = rolluper.Close() + }) + + var stats []database.TemplateUsageStat + var err error + require.Eventually(t, func() bool { + stats, err = db.GetTemplateUsageStats(ctx, database.GetTemplateUsageStatsParams{ + StartTime: anHourAndSixMonthsAgo.Add(-time.Minute), + EndTime: anHourAgo, + }) + if err != nil { + // Stop looping on unexpected errors. + return !errors.Is(err, sql.ErrNoRows) + } + return len(stats) > 0 + }, testutil.WaitShort, testutil.IntervalFast) + require.NoError(t, err) + require.Len(t, stats, 1) + + require.Equal(t, database.TemplateUsageStat{ + TemplateID: tpl.ID, + UserID: user.ID, + StartTime: wags1.CreatedAt, + EndTime: wags1.CreatedAt.Add(30 * time.Minute), + MedianLatencyMs: sql.NullFloat64{Float64: 1, Valid: true}, + UsageMins: 3, + ReconnectingPtyMins: 2, + AppUsageMins: database.StringMapOfInt{ + app.Slug: 2, + }, + }, stats[0]) +} diff --git a/coderd/database/lock.go b/coderd/database/lock.go index a007e5e03e752f..65dd6eb84a832a 100644 --- a/coderd/database/lock.go +++ b/coderd/database/lock.go @@ -6,10 +6,9 @@ import "hash/fnv" // change. If locks are deprecated, they should be kept in this list to avoid // reusing the same ID. const ( - // Keep the unused iota here so we don't need + 1 every time - lockIDUnused = iota - LockIDDeploymentSetup + LockIDDeploymentSetup = iota + 1 LockIDEnterpriseDeploymentSetup + LockIDDBRollup ) // GenLockID generates a unique and consistent lock ID from a given string. From c9bd6af1bf8e52cffeb1cb5b0668cc33ed5e3be7 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Tue, 19 Mar 2024 17:59:31 +0200 Subject: [PATCH 07/19] test(coderd): fix insights tests --- coderd/database/queries.sql.go | 3 ++- coderd/database/queries/insights.sql | 3 ++- coderd/insights_test.go | 13 +++++++++++-- 3 files changed, 15 insertions(+), 4 deletions(-) diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index ac095e3c89131c..62c4a03de3a8eb 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -2499,7 +2499,8 @@ WITH SELECT COALESCE( MAX(start_time) - '1 hour'::interval, - NOW() - '6 months'::interval + -- TODO(mafredri): Fix this, required for tests to pass. + NOW() - '2 years'::interval ) AS t FROM template_usage_stats diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index bffb2bf5fdb5db..5282868bdd9d1b 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -349,7 +349,8 @@ WITH SELECT COALESCE( MAX(start_time) - '1 hour'::interval, - NOW() - '6 months'::interval + -- TODO(mafredri): Fix this, required for tests to pass. + NOW() - '2 years'::interval ) AS t FROM template_usage_stats diff --git a/coderd/insights_test.go b/coderd/insights_test.go index ad748a3132510c..2cf03569b66d17 100644 --- a/coderd/insights_test.go +++ b/coderd/insights_test.go @@ -122,7 +122,8 @@ func TestUserActivityInsights_SanityCheck(t *testing.T) { logger := slogtest.Make(t, nil) client := coderdtest.New(t, &coderdtest.Options{ IncludeProvisionerDaemon: true, - AgentStatsRefreshInterval: time.Millisecond * 100, + AgentStatsRefreshInterval: time.Millisecond * 50, + DBRollupInterval: time.Millisecond * 100, }) // Create two users, one that will appear in the report and another that @@ -476,13 +477,14 @@ func TestTemplateInsights_Golden(t *testing.T) { prepare := func(t *testing.T, templates []*testTemplate, users []*testUser, testData map[*testWorkspace]testDataGen) *codersdk.Client { logger := slogtest.Make(t, &slogtest.Options{IgnoreErrors: false}).Leveled(slog.LevelDebug) - db, pubsub := dbtestutil.NewDB(t) + db, pubsub := dbtestutil.NewDB(t, dbtestutil.WithDumpOnFailure()) client := coderdtest.New(t, &coderdtest.Options{ Database: db, Pubsub: pubsub, Logger: &logger, IncludeProvisionerDaemon: true, AgentStatsRefreshInterval: time.Hour, // Not relevant for this test. + DBRollupInterval: 100 * time.Millisecond, }) firstUser := coderdtest.CreateFirstUser(t, client) @@ -1202,6 +1204,9 @@ func TestTemplateInsights_Golden(t *testing.T) { templates, users, testData := prepareFixtureAndTestData(t, tt.makeFixture, tt.makeTestData) client := prepare(t, templates, users, testData) + // TODO(mafredri): Remove the need for this. + time.Sleep(3 * time.Second) + for _, req := range tt.requests { req := req t.Run(req.name, func(t *testing.T) { @@ -1390,6 +1395,7 @@ func TestUserActivityInsights_Golden(t *testing.T) { Logger: &logger, IncludeProvisionerDaemon: true, AgentStatsRefreshInterval: time.Hour, // Not relevant for this test. + DBRollupInterval: 100 * time.Millisecond, }) firstUser := coderdtest.CreateFirstUser(t, client) @@ -1976,6 +1982,9 @@ func TestUserActivityInsights_Golden(t *testing.T) { templates, users, testData := prepareFixtureAndTestData(t, tt.makeFixture, tt.makeTestData) client := prepare(t, templates, users, testData) + // TODO(mafredri): Remove the need for this. + time.Sleep(3 * time.Second) + for _, req := range tt.requests { req := req t.Run(req.name, func(t *testing.T) { From 9037b25def98ea4cd7984a8aca1d0e90d4e40a55 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Mon, 18 Mar 2024 20:27:21 +0200 Subject: [PATCH 08/19] feat(coderd/database): rewrite `GetTemplateInsights` to use `template_usage_stats` --- coderd/database/dbmem/dbmem.go | 4 +- coderd/database/querier.go | 12 +- coderd/database/queries.sql.go | 117 ++++++++++++------ coderd/database/queries/insights.sql | 91 +++++++++----- coderd/insights.go | 45 +------ ...es_three_weeks_second_template.json.golden | 4 +- ...ks_second_template_only_report.json.golden | 4 +- ..._workspaces_week_all_templates.json.golden | 9 +- ...orkspaces_week_deployment_wide.json.golden | 9 +- ...workspaces_week_first_template.json.golden | 4 +- ...r_timezone_(S\303\243o_Paulo).json.golden" | 4 +- ...orkspaces_week_second_template.json.golden | 8 +- ...workspaces_week_third_template.json.golden | 8 +- ...kly_aggregated_deployment_wide.json.golden | 9 +- ...ekly_aggregated_first_template.json.golden | 4 +- ...es_weekly_aggregated_templates.json.golden | 9 +- 16 files changed, 172 insertions(+), 169 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index bfccd2acd2c92f..46e6e326cbbcf9 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -3290,8 +3290,8 @@ func (q *FakeQuerier) GetTemplateInsights(_ context.Context, arg database.GetTem } result := database.GetTemplateInsightsRow{ - TemplateIDs: templateIDs, - ActiveUserIDs: activeUserIDs, + TemplateIDs: templateIDs, + ActiveUsers: int64(len(activeUserIDs)), } for _, intervals := range appUsageIntervalsByUser { for _, interval := range intervals { diff --git a/coderd/database/querier.go b/coderd/database/querier.go index 87d5d7771130df..ee2c1b39ad369e 100644 --- a/coderd/database/querier.go +++ b/coderd/database/querier.go @@ -178,9 +178,15 @@ type sqlcQuerier interface { GetTemplateByID(ctx context.Context, id uuid.UUID) (Template, error) GetTemplateByOrganizationAndName(ctx context.Context, arg GetTemplateByOrganizationAndNameParams) (Template, error) GetTemplateDAUs(ctx context.Context, arg GetTemplateDAUsParams) ([]GetTemplateDAUsRow, error) - // GetTemplateInsights has a granularity of 5 minutes where if a session/app was - // in use during a minute, we will add 5 minutes to the total usage for that - // session/app (per user). + // GetTemplateInsights returns the aggregate user-produced usage of all + // workspaces in a given timeframe. The template IDs, active users, and + // usage_seconds all reflect any usage in the template, including apps. + // + // When combining data from multiple templates, we must make a guess at + // how the user behaved for the 30 minute interval. In this case we make + // the assumption that if the user used two workspaces for 15 minutes, + // they did so sequentially, thus we sum the usage up to a maximum of + // 30 minutes with LEAST(SUM(n), 30). GetTemplateInsights(ctx context.Context, arg GetTemplateInsightsParams) (GetTemplateInsightsRow, error) // GetTemplateInsightsByInterval returns all intervals between start and end // time, if end time is a partial interval, it will be included in the results and diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 62c4a03de3a8eb..32d46abd9a7d5c 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -1894,37 +1894,58 @@ func (q *sqlQuerier) GetTemplateAppInsightsByTemplate(ctx context.Context, arg G } const getTemplateInsights = `-- name: GetTemplateInsights :one -WITH agent_stats_by_interval_and_user AS ( - SELECT - date_trunc('minute', was.created_at), - was.user_id, - array_agg(was.template_id) AS template_ids, - CASE WHEN SUM(was.session_count_vscode) > 0 THEN 60 ELSE 0 END AS usage_vscode_seconds, - CASE WHEN SUM(was.session_count_jetbrains) > 0 THEN 60 ELSE 0 END AS usage_jetbrains_seconds, - CASE WHEN SUM(was.session_count_reconnecting_pty) > 0 THEN 60 ELSE 0 END AS usage_reconnecting_pty_seconds, - CASE WHEN SUM(was.session_count_ssh) > 0 THEN 60 ELSE 0 END AS usage_ssh_seconds - FROM workspace_agent_stats was - WHERE - was.created_at >= $1::timestamptz - AND was.created_at < $2::timestamptz - 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 date_trunc('minute', was.created_at), was.user_id -), template_ids AS ( - SELECT array_agg(DISTINCT template_id) AS ids - FROM agent_stats_by_interval_and_user, unnest(template_ids) template_id - WHERE template_id IS NOT NULL -) +WITH + insights AS ( + SELECT + user_id, + -- See motivation in GetTemplateInsights for LEAST(SUM(n), 30). + LEAST(SUM(usage_mins), 30) AS usage_mins, + LEAST(SUM(ssh_mins), 30) AS ssh_mins, + LEAST(SUM(sftp_mins), 30) AS sftp_mins, + LEAST(SUM(reconnecting_pty_mins), 30) AS reconnecting_pty_mins, + LEAST(SUM(vscode_mins), 30) AS vscode_mins, + LEAST(SUM(jetbrains_mins), 30) AS jetbrains_mins + FROM + template_usage_stats + WHERE + start_time >= $1::timestamptz + AND end_time <= $2::timestamptz + AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN template_id = ANY($3::uuid[]) ELSE TRUE END + GROUP BY + start_time, user_id + ), + templates AS ( + SELECT + array_agg(DISTINCT template_id) AS template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE ssh_mins > 0) AS ssh_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE sftp_mins > 0) AS sftp_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE reconnecting_pty_mins > 0) AS reconnecting_pty_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE vscode_mins > 0) AS vscode_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE jetbrains_mins > 0) AS jetbrains_template_ids + FROM + template_usage_stats + WHERE + start_time >= $1::timestamptz + AND end_time <= $2::timestamptz + AND CASE WHEN COALESCE(array_length($3::uuid[], 1), 0) > 0 THEN template_id = ANY($3::uuid[]) ELSE TRUE END + ) SELECT - COALESCE((SELECT ids FROM template_ids), '{}')::uuid[] AS template_ids, - -- 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 agent_stats_by_interval_and_user + COALESCE((SELECT template_ids FROM templates), '{}')::uuid[] AS template_ids, -- Includes app usage. + COALESCE((SELECT ssh_template_ids FROM templates), '{}')::uuid[] AS ssh_template_ids, + COALESCE((SELECT sftp_template_ids FROM templates), '{}')::uuid[] AS sftp_template_ids, + COALESCE((SELECT reconnecting_pty_template_ids FROM templates), '{}')::uuid[] AS reconnecting_pty_template_ids, + COALESCE((SELECT vscode_template_ids FROM templates), '{}')::uuid[] AS vscode_template_ids, + COALESCE((SELECT jetbrains_template_ids FROM templates), '{}')::uuid[] AS jetbrains_template_ids, + COALESCE(COUNT(DISTINCT user_id), 0)::bigint AS active_users, -- Includes app usage. + COALESCE(SUM(usage_mins) * 60, 0)::bigint AS usage_total_seconds, -- Includes app usage. + COALESCE(SUM(ssh_mins) * 60, 0)::bigint AS usage_ssh_seconds, + COALESCE(SUM(sftp_mins) * 60, 0)::bigint AS usage_sftp_seconds, + COALESCE(SUM(reconnecting_pty_mins) * 60, 0)::bigint AS usage_reconnecting_pty_seconds, + COALESCE(SUM(vscode_mins) * 60, 0)::bigint AS usage_vscode_seconds, + COALESCE(SUM(jetbrains_mins) * 60, 0)::bigint AS usage_jetbrains_seconds +FROM + insights ` type GetTemplateInsightsParams struct { @@ -1935,26 +1956,46 @@ type GetTemplateInsightsParams struct { type GetTemplateInsightsRow struct { TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"` - ActiveUserIDs []uuid.UUID `db:"active_user_ids" json:"active_user_ids"` + SshTemplateIds []uuid.UUID `db:"ssh_template_ids" json:"ssh_template_ids"` + SftpTemplateIds []uuid.UUID `db:"sftp_template_ids" json:"sftp_template_ids"` + ReconnectingPtyTemplateIds []uuid.UUID `db:"reconnecting_pty_template_ids" json:"reconnecting_pty_template_ids"` + VscodeTemplateIds []uuid.UUID `db:"vscode_template_ids" json:"vscode_template_ids"` + JetbrainsTemplateIds []uuid.UUID `db:"jetbrains_template_ids" json:"jetbrains_template_ids"` + ActiveUsers int64 `db:"active_users" json:"active_users"` + UsageTotalSeconds int64 `db:"usage_total_seconds" json:"usage_total_seconds"` + UsageSshSeconds int64 `db:"usage_ssh_seconds" json:"usage_ssh_seconds"` + UsageSftpSeconds int64 `db:"usage_sftp_seconds" json:"usage_sftp_seconds"` + UsageReconnectingPtySeconds int64 `db:"usage_reconnecting_pty_seconds" json:"usage_reconnecting_pty_seconds"` 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"` - UsageSshSeconds int64 `db:"usage_ssh_seconds" json:"usage_ssh_seconds"` } -// GetTemplateInsights has a granularity of 5 minutes where if a session/app was -// in use during a minute, we will add 5 minutes to the total usage for that -// session/app (per user). +// GetTemplateInsights returns the aggregate user-produced usage of all +// workspaces in a given timeframe. The template IDs, active users, and +// usage_seconds all reflect any usage in the template, including apps. +// +// When combining data from multiple templates, we must make a guess at +// how the user behaved for the 30 minute interval. In this case we make +// the assumption that if the user used two workspaces for 15 minutes, +// they did so sequentially, thus we sum the usage up to a maximum of +// 30 minutes with LEAST(SUM(n), 30). 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), - pq.Array(&i.ActiveUserIDs), + pq.Array(&i.SshTemplateIds), + pq.Array(&i.SftpTemplateIds), + pq.Array(&i.ReconnectingPtyTemplateIds), + pq.Array(&i.VscodeTemplateIds), + pq.Array(&i.JetbrainsTemplateIds), + &i.ActiveUsers, + &i.UsageTotalSeconds, + &i.UsageSshSeconds, + &i.UsageSftpSeconds, + &i.UsageReconnectingPtySeconds, &i.UsageVscodeSeconds, &i.UsageJetbrainsSeconds, - &i.UsageReconnectingPtySeconds, - &i.UsageSshSeconds, ) return i, err } diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index 5282868bdd9d1b..28b9d7c94526ee 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -99,40 +99,67 @@ GROUP BY users.id, username, avatar_url ORDER BY user_id ASC; -- name: GetTemplateInsights :one --- GetTemplateInsights has a granularity of 5 minutes where if a session/app was --- in use during a minute, we will add 5 minutes to the total usage for that --- session/app (per user). -WITH agent_stats_by_interval_and_user AS ( - SELECT - date_trunc('minute', was.created_at), - was.user_id, - array_agg(was.template_id) AS template_ids, - CASE WHEN SUM(was.session_count_vscode) > 0 THEN 60 ELSE 0 END AS usage_vscode_seconds, - CASE WHEN SUM(was.session_count_jetbrains) > 0 THEN 60 ELSE 0 END AS usage_jetbrains_seconds, - CASE WHEN SUM(was.session_count_reconnecting_pty) > 0 THEN 60 ELSE 0 END AS usage_reconnecting_pty_seconds, - CASE WHEN SUM(was.session_count_ssh) > 0 THEN 60 ELSE 0 END AS usage_ssh_seconds - FROM workspace_agent_stats was - WHERE - was.created_at >= @start_time::timestamptz - AND was.created_at < @end_time::timestamptz - 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 date_trunc('minute', was.created_at), was.user_id -), template_ids AS ( - SELECT array_agg(DISTINCT template_id) AS ids - FROM agent_stats_by_interval_and_user, unnest(template_ids) template_id - WHERE template_id IS NOT NULL -) +-- GetTemplateInsights returns the aggregate user-produced usage of all +-- workspaces in a given timeframe. The template IDs, active users, and +-- usage_seconds all reflect any usage in the template, including apps. +-- +-- When combining data from multiple templates, we must make a guess at +-- how the user behaved for the 30 minute interval. In this case we make +-- the assumption that if the user used two workspaces for 15 minutes, +-- they did so sequentially, thus we sum the usage up to a maximum of +-- 30 minutes with LEAST(SUM(n), 30). +WITH + insights AS ( + SELECT + user_id, + -- See motivation in GetTemplateInsights for LEAST(SUM(n), 30). + LEAST(SUM(usage_mins), 30) AS usage_mins, + LEAST(SUM(ssh_mins), 30) AS ssh_mins, + LEAST(SUM(sftp_mins), 30) AS sftp_mins, + LEAST(SUM(reconnecting_pty_mins), 30) AS reconnecting_pty_mins, + LEAST(SUM(vscode_mins), 30) AS vscode_mins, + LEAST(SUM(jetbrains_mins), 30) AS jetbrains_mins + FROM + template_usage_stats + WHERE + start_time >= @start_time::timestamptz + AND end_time <= @end_time::timestamptz + AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN template_id = ANY(@template_ids::uuid[]) ELSE TRUE END + GROUP BY + start_time, user_id + ), + templates AS ( + SELECT + array_agg(DISTINCT template_id) AS template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE ssh_mins > 0) AS ssh_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE sftp_mins > 0) AS sftp_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE reconnecting_pty_mins > 0) AS reconnecting_pty_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE vscode_mins > 0) AS vscode_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE jetbrains_mins > 0) AS jetbrains_template_ids + FROM + template_usage_stats + WHERE + start_time >= @start_time::timestamptz + AND end_time <= @end_time::timestamptz + AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN template_id = ANY(@template_ids::uuid[]) ELSE TRUE END + ) SELECT - COALESCE((SELECT ids FROM template_ids), '{}')::uuid[] AS template_ids, - -- 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 agent_stats_by_interval_and_user; + COALESCE((SELECT template_ids FROM templates), '{}')::uuid[] AS template_ids, -- Includes app usage. + COALESCE((SELECT ssh_template_ids FROM templates), '{}')::uuid[] AS ssh_template_ids, + COALESCE((SELECT sftp_template_ids FROM templates), '{}')::uuid[] AS sftp_template_ids, + COALESCE((SELECT reconnecting_pty_template_ids FROM templates), '{}')::uuid[] AS reconnecting_pty_template_ids, + COALESCE((SELECT vscode_template_ids FROM templates), '{}')::uuid[] AS vscode_template_ids, + COALESCE((SELECT jetbrains_template_ids FROM templates), '{}')::uuid[] AS jetbrains_template_ids, + COALESCE(COUNT(DISTINCT user_id), 0)::bigint AS active_users, -- Includes app usage. + COALESCE(SUM(usage_mins) * 60, 0)::bigint AS usage_total_seconds, -- Includes app usage. + COALESCE(SUM(ssh_mins) * 60, 0)::bigint AS usage_ssh_seconds, + COALESCE(SUM(sftp_mins) * 60, 0)::bigint AS usage_sftp_seconds, + COALESCE(SUM(reconnecting_pty_mins) * 60, 0)::bigint AS usage_reconnecting_pty_seconds, + COALESCE(SUM(vscode_mins) * 60, 0)::bigint AS usage_vscode_seconds, + COALESCE(SUM(jetbrains_mins) * 60, 0)::bigint AS usage_jetbrains_seconds +FROM + insights; -- name: GetTemplateInsightsByTemplate :many WITH agent_stats_by_interval_and_user AS ( diff --git a/coderd/insights.go b/coderd/insights.go index 214eae5510d4c0..b38e7aecdeb026 100644 --- a/coderd/insights.go +++ b/coderd/insights.go @@ -395,8 +395,8 @@ func (api *API) insightsTemplates(rw http.ResponseWriter, r *http.Request) { resp.Report = &codersdk.TemplateInsightsReport{ StartTime: startTime, EndTime: endTime, - TemplateIDs: convertTemplateInsightsTemplateIDs(usage, appUsage), - ActiveUsers: convertTemplateInsightsActiveUsers(usage, appUsage), + TemplateIDs: usage.TemplateIDs, + ActiveUsers: usage.ActiveUsers, AppsUsage: convertTemplateInsightsApps(usage, appUsage), ParametersUsage: parametersUsage, } @@ -416,39 +416,6 @@ func (api *API) insightsTemplates(rw http.ResponseWriter, r *http.Request) { httpapi.Write(ctx, rw, http.StatusOK, resp) } -func convertTemplateInsightsTemplateIDs(usage database.GetTemplateInsightsRow, appUsage []database.GetTemplateAppInsightsRow) []uuid.UUID { - templateIDSet := make(map[uuid.UUID]struct{}) - for _, id := range usage.TemplateIDs { - templateIDSet[id] = struct{}{} - } - for _, app := range appUsage { - for _, id := range app.TemplateIDs { - templateIDSet[id] = struct{}{} - } - } - templateIDs := make([]uuid.UUID, 0, len(templateIDSet)) - for id := range templateIDSet { - templateIDs = append(templateIDs, id) - } - slices.SortFunc(templateIDs, func(a, b uuid.UUID) int { - return slice.Ascending(a.String(), b.String()) - }) - return templateIDs -} - -func convertTemplateInsightsActiveUsers(usage database.GetTemplateInsightsRow, appUsage []database.GetTemplateAppInsightsRow) int64 { - activeUserIDSet := make(map[uuid.UUID]struct{}) - for _, id := range usage.ActiveUserIDs { - activeUserIDSet[id] = struct{}{} - } - for _, app := range appUsage { - for _, id := range app.ActiveUserIDs { - activeUserIDSet[id] = struct{}{} - } - } - return int64(len(activeUserIDSet)) -} - // convertTemplateInsightsApps builds the list of builtin apps and template apps // from the provided database rows, builtin apps are implicitly a part of all // templates. @@ -456,7 +423,7 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage // Builtin apps. apps := []codersdk.TemplateAppUsage{ { - TemplateIDs: usage.TemplateIDs, + TemplateIDs: usage.VscodeTemplateIds, Type: codersdk.TemplateAppsTypeBuiltin, DisplayName: codersdk.TemplateBuiltinAppDisplayNameVSCode, Slug: "vscode", @@ -464,7 +431,7 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage Seconds: usage.UsageVscodeSeconds, }, { - TemplateIDs: usage.TemplateIDs, + TemplateIDs: usage.JetbrainsTemplateIds, Type: codersdk.TemplateAppsTypeBuiltin, DisplayName: codersdk.TemplateBuiltinAppDisplayNameJetBrains, Slug: "jetbrains", @@ -478,7 +445,7 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage // condition finding the corresponding app entry in appUsage is: // !app.IsApp && app.AccessMethod == "terminal" && app.SlugOrPort == "" { - TemplateIDs: usage.TemplateIDs, + TemplateIDs: usage.ReconnectingPtyTemplateIds, Type: codersdk.TemplateAppsTypeBuiltin, DisplayName: codersdk.TemplateBuiltinAppDisplayNameWebTerminal, Slug: "reconnecting-pty", @@ -486,7 +453,7 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage Seconds: usage.UsageReconnectingPtySeconds, }, { - TemplateIDs: usage.TemplateIDs, + TemplateIDs: usage.SshTemplateIds, Type: codersdk.TemplateAppsTypeBuiltin, DisplayName: codersdk.TemplateBuiltinAppDisplayNameSSH, Slug: "ssh", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template.json.golden index 07c3f526073340..e9a7e1a8cc99f8 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template.json.golden @@ -18,9 +18,7 @@ "seconds": 3600 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000002" - ], + "template_ids": [], "type": "builtin", "display_name": "JetBrains", "slug": "jetbrains", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template_only_report.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template_only_report.json.golden index e3a1a2cd3974fb..3107db75932b41 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template_only_report.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_three_weeks_second_template_only_report.json.golden @@ -18,9 +18,7 @@ "seconds": 3600 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000002" - ], + "template_ids": [], "type": "builtin", "display_name": "JetBrains", "slug": "jetbrains", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_all_templates.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_all_templates.json.golden index 664e2fed8f250e..e7634e3a603892 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_all_templates.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_all_templates.json.golden @@ -12,8 +12,7 @@ { "template_ids": [ "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000002" ], "type": "builtin", "display_name": "Visual Studio Code", @@ -23,9 +22,7 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000001" ], "type": "builtin", "display_name": "JetBrains", @@ -35,8 +32,6 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", "00000000-0000-0000-0000-000000000003" ], "type": "builtin", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_deployment_wide.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_deployment_wide.json.golden index 664e2fed8f250e..e7634e3a603892 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_deployment_wide.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_deployment_wide.json.golden @@ -12,8 +12,7 @@ { "template_ids": [ "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000002" ], "type": "builtin", "display_name": "Visual Studio Code", @@ -23,9 +22,7 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000001" ], "type": "builtin", "display_name": "JetBrains", @@ -35,8 +32,6 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", "00000000-0000-0000-0000-000000000003" ], "type": "builtin", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_first_template.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_first_template.json.golden index d96469dc5c7242..37dc61b2d085fa 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_first_template.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_first_template.json.golden @@ -28,9 +28,7 @@ "seconds": 120 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000001" - ], + "template_ids": [], "type": "builtin", "display_name": "Web Terminal", "slug": "reconnecting-pty", diff --git "a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_other_timezone_(S\303\243o_Paulo).json.golden" "b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_other_timezone_(S\303\243o_Paulo).json.golden" index 8f447e4112dd02..76ec01508a0a5b 100644 --- "a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_other_timezone_(S\303\243o_Paulo).json.golden" +++ "b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_other_timezone_(S\303\243o_Paulo).json.golden" @@ -30,9 +30,7 @@ "seconds": 120 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000001" - ], + "template_ids": [], "type": "builtin", "display_name": "Web Terminal", "slug": "reconnecting-pty", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_second_template.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_second_template.json.golden index b15cba10a8520a..ab5ac935556afe 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_second_template.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_second_template.json.golden @@ -18,9 +18,7 @@ "seconds": 3600 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000002" - ], + "template_ids": [], "type": "builtin", "display_name": "JetBrains", "slug": "jetbrains", @@ -28,9 +26,7 @@ "seconds": 0 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000002" - ], + "template_ids": [], "type": "builtin", "display_name": "Web Terminal", "slug": "reconnecting-pty", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_third_template.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_third_template.json.golden index ea4002e09f152d..e10e78fa9c4c86 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_week_third_template.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_week_third_template.json.golden @@ -8,9 +8,7 @@ "active_users": 1, "apps_usage": [ { - "template_ids": [ - "00000000-0000-0000-0000-000000000003" - ], + "template_ids": [], "type": "builtin", "display_name": "Visual Studio Code", "slug": "vscode", @@ -18,9 +16,7 @@ "seconds": 0 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000003" - ], + "template_ids": [], "type": "builtin", "display_name": "JetBrains", "slug": "jetbrains", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_deployment_wide.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_deployment_wide.json.golden index e6f3425f27aa5c..2cdab497170069 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_deployment_wide.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_deployment_wide.json.golden @@ -12,8 +12,7 @@ { "template_ids": [ "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000002" ], "type": "builtin", "display_name": "Visual Studio Code", @@ -23,9 +22,7 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000001" ], "type": "builtin", "display_name": "JetBrains", @@ -35,8 +32,6 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", "00000000-0000-0000-0000-000000000003" ], "type": "builtin", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_first_template.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_first_template.json.golden index 3c0483f7feb48a..1c25aea8808fd2 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_first_template.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_first_template.json.golden @@ -28,9 +28,7 @@ "seconds": 120 }, { - "template_ids": [ - "00000000-0000-0000-0000-000000000001" - ], + "template_ids": [], "type": "builtin", "display_name": "Web Terminal", "slug": "reconnecting-pty", diff --git a/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_templates.json.golden b/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_templates.json.golden index 185a7fe143a2bb..bf096567592eea 100644 --- a/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_templates.json.golden +++ b/coderd/testdata/insights/template/multiple_users_and_workspaces_weekly_aggregated_templates.json.golden @@ -12,8 +12,7 @@ { "template_ids": [ "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000002" ], "type": "builtin", "display_name": "Visual Studio Code", @@ -23,9 +22,7 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", - "00000000-0000-0000-0000-000000000003" + "00000000-0000-0000-0000-000000000001" ], "type": "builtin", "display_name": "JetBrains", @@ -35,8 +32,6 @@ }, { "template_ids": [ - "00000000-0000-0000-0000-000000000001", - "00000000-0000-0000-0000-000000000002", "00000000-0000-0000-0000-000000000003" ], "type": "builtin", From 4da99d82d5326f9baffbfc2cc40263d0dea5bf24 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 13:55:51 +0000 Subject: [PATCH 09/19] fix: implement `GetTemplateInsights` in dbmem --- coderd/database/dbmem/dbmem.go | 197 +++++++++++++++++++++++++-------- 1 file changed, 150 insertions(+), 47 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index 46e6e326cbbcf9..18401dfddaf2b2 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -16,6 +16,7 @@ import ( "github.com/google/uuid" "github.com/lib/pq" + "golang.org/x/exp/constraints" "golang.org/x/exp/maps" "golang.org/x/exp/slices" "golang.org/x/xerrors" @@ -791,6 +792,13 @@ func tagsSubset(m1, m2 map[string]string) bool { // default tags when no tag is specified for a provisioner or job var tagsUntagged = provisionersdk.MutateTags(uuid.Nil, nil) +func least[T constraints.Ordered](a, b T) T { + if a < b { + return a + } + return b +} + func (*FakeQuerier) AcquireLock(_ context.Context, _ int64) error { return xerrors.New("AcquireLock must only be called within a transaction") } @@ -3237,71 +3245,166 @@ func (q *FakeQuerier) GetTemplateInsights(_ context.Context, arg database.GetTem return database.GetTemplateInsightsRow{}, err } - templateIDSet := make(map[uuid.UUID]struct{}) - appUsageIntervalsByUser := make(map[uuid.UUID]map[time.Time]*database.GetTemplateInsightsRow) - q.mutex.RLock() defer q.mutex.RUnlock() - for _, s := range q.workspaceAgentStats { - if s.CreatedAt.Before(arg.StartTime) || s.CreatedAt.Equal(arg.EndTime) || s.CreatedAt.After(arg.EndTime) { + /* + WITH + */ + + /* + insights AS ( + SELECT + user_id, + -- See motivation in GetTemplateInsights for LEAST(SUM(n), 30). + LEAST(SUM(usage_mins), 30) AS usage_mins, + LEAST(SUM(ssh_mins), 30) AS ssh_mins, + LEAST(SUM(sftp_mins), 30) AS sftp_mins, + LEAST(SUM(reconnecting_pty_mins), 30) AS reconnecting_pty_mins, + LEAST(SUM(vscode_mins), 30) AS vscode_mins, + LEAST(SUM(jetbrains_mins), 30) AS jetbrains_mins + FROM + template_usage_stats + WHERE + start_time >= @start_time::timestamptz + AND end_time <= @end_time::timestamptz + AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN template_id = ANY(@template_ids::uuid[]) ELSE TRUE END + GROUP BY + start_time, user_id + ), + */ + + type insightsGroupBy struct { + StartTime time.Time + UserID uuid.UUID + } + type insightsRow struct { + insightsGroupBy + UsageMins int16 + SSHMins int16 + SFTPMins int16 + ReconnectingPTYMins int16 + VSCodeMins int16 + JetBrainsMins int16 + } + insights := make(map[insightsGroupBy]insightsRow) + for _, stat := range q.templateUsageStats { + if stat.StartTime.Before(arg.StartTime) || stat.EndTime.After(arg.EndTime) { continue } - if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, s.TemplateID) { + if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, stat.TemplateID) { continue } - if s.ConnectionCount == 0 { - continue + key := insightsGroupBy{ + StartTime: stat.StartTime, + UserID: stat.UserID, + } + row, ok := insights[key] + if !ok { + row = insightsRow{ + insightsGroupBy: key, + } } + row.UsageMins = least(row.UsageMins+stat.UsageMins, 30) + row.SSHMins = least(row.SSHMins+stat.SshMins, 30) + row.SFTPMins = least(row.SFTPMins+stat.SftpMins, 30) + row.ReconnectingPTYMins = least(row.ReconnectingPTYMins+stat.ReconnectingPtyMins, 30) + row.VSCodeMins = least(row.VSCodeMins+stat.VscodeMins, 30) + row.JetBrainsMins = least(row.JetBrainsMins+stat.JetbrainsMins, 30) + insights[key] = row + } - templateIDSet[s.TemplateID] = struct{}{} - if appUsageIntervalsByUser[s.UserID] == nil { - appUsageIntervalsByUser[s.UserID] = make(map[time.Time]*database.GetTemplateInsightsRow) + /* + templates AS ( + SELECT + array_agg(DISTINCT template_id) AS template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE ssh_mins > 0) AS ssh_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE sftp_mins > 0) AS sftp_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE reconnecting_pty_mins > 0) AS reconnecting_pty_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE vscode_mins > 0) AS vscode_template_ids, + array_agg(DISTINCT template_id) FILTER (WHERE jetbrains_mins > 0) AS jetbrains_template_ids + FROM + template_usage_stats + WHERE + start_time >= @start_time::timestamptz + AND end_time <= @end_time::timestamptz + AND CASE WHEN COALESCE(array_length(@template_ids::uuid[], 1), 0) > 0 THEN template_id = ANY(@template_ids::uuid[]) ELSE TRUE END + ) + */ + + type templateRow struct { + TemplateIDs []uuid.UUID + SSHTemplateIDs []uuid.UUID + SFTPTemplateIDs []uuid.UUID + ReconnectingPTYIDs []uuid.UUID + VSCodeTemplateIDs []uuid.UUID + JetBrainsTemplateIDs []uuid.UUID + } + templates := templateRow{} + for _, stat := range q.templateUsageStats { + if stat.StartTime.Before(arg.StartTime) || stat.EndTime.After(arg.EndTime) { + continue } - t := s.CreatedAt.Truncate(time.Minute) - if _, ok := appUsageIntervalsByUser[s.UserID][t]; !ok { - appUsageIntervalsByUser[s.UserID][t] = &database.GetTemplateInsightsRow{} + if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, stat.TemplateID) { + continue } - - if s.SessionCountJetBrains > 0 { - appUsageIntervalsByUser[s.UserID][t].UsageJetbrainsSeconds = 60 + templates.TemplateIDs = append(templates.TemplateIDs, stat.TemplateID) + if stat.SshMins > 0 { + templates.SSHTemplateIDs = append(templates.SSHTemplateIDs, stat.TemplateID) } - if s.SessionCountVSCode > 0 { - appUsageIntervalsByUser[s.UserID][t].UsageVscodeSeconds = 60 + if stat.SftpMins > 0 { + templates.SFTPTemplateIDs = append(templates.SFTPTemplateIDs, stat.TemplateID) } - if s.SessionCountReconnectingPTY > 0 { - appUsageIntervalsByUser[s.UserID][t].UsageReconnectingPtySeconds = 60 + if stat.ReconnectingPtyMins > 0 { + templates.ReconnectingPTYIDs = append(templates.ReconnectingPTYIDs, stat.TemplateID) } - if s.SessionCountSSH > 0 { - appUsageIntervalsByUser[s.UserID][t].UsageSshSeconds = 60 + if stat.VscodeMins > 0 { + templates.VSCodeTemplateIDs = append(templates.VSCodeTemplateIDs, stat.TemplateID) + } + if stat.JetbrainsMins > 0 { + templates.JetBrainsTemplateIDs = append(templates.JetBrainsTemplateIDs, stat.TemplateID) } } - 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()) - }) - activeUserIDs := make([]uuid.UUID, 0, len(appUsageIntervalsByUser)) - for userID := range appUsageIntervalsByUser { - activeUserIDs = append(activeUserIDs, userID) - } + /* + SELECT + COALESCE((SELECT template_ids FROM templates), '{}')::uuid[] AS template_ids, -- Includes app usage. + COALESCE((SELECT ssh_template_ids FROM templates), '{}')::uuid[] AS ssh_template_ids, + COALESCE((SELECT sftp_template_ids FROM templates), '{}')::uuid[] AS sftp_template_ids, + COALESCE((SELECT reconnecting_pty_template_ids FROM templates), '{}')::uuid[] AS reconnecting_pty_template_ids, + COALESCE((SELECT vscode_template_ids FROM templates), '{}')::uuid[] AS vscode_template_ids, + COALESCE((SELECT jetbrains_template_ids FROM templates), '{}')::uuid[] AS jetbrains_template_ids, + COALESCE(COUNT(DISTINCT user_id), 0)::bigint AS active_users, -- Includes app usage. + COALESCE(SUM(usage_mins) * 60, 0)::bigint AS usage_total_seconds, -- Includes app usage. + COALESCE(SUM(ssh_mins) * 60, 0)::bigint AS usage_ssh_seconds, + COALESCE(SUM(sftp_mins) * 60, 0)::bigint AS usage_sftp_seconds, + COALESCE(SUM(reconnecting_pty_mins) * 60, 0)::bigint AS usage_reconnecting_pty_seconds, + COALESCE(SUM(vscode_mins) * 60, 0)::bigint AS usage_vscode_seconds, + COALESCE(SUM(jetbrains_mins) * 60, 0)::bigint AS usage_jetbrains_seconds + FROM + insights; + */ - result := database.GetTemplateInsightsRow{ - TemplateIDs: templateIDs, - ActiveUsers: int64(len(activeUserIDs)), - } - for _, intervals := range appUsageIntervalsByUser { - for _, interval := range intervals { - result.UsageJetbrainsSeconds += interval.UsageJetbrainsSeconds - result.UsageVscodeSeconds += interval.UsageVscodeSeconds - result.UsageReconnectingPtySeconds += interval.UsageReconnectingPtySeconds - result.UsageSshSeconds += interval.UsageSshSeconds - } - } - return result, nil + var row database.GetTemplateInsightsRow + row.TemplateIDs = uniqueSortedUUIDs(templates.TemplateIDs) + row.SshTemplateIds = uniqueSortedUUIDs(templates.SSHTemplateIDs) + row.SftpTemplateIds = uniqueSortedUUIDs(templates.SFTPTemplateIDs) + row.ReconnectingPtyTemplateIds = uniqueSortedUUIDs(templates.ReconnectingPTYIDs) + row.VscodeTemplateIds = uniqueSortedUUIDs(templates.VSCodeTemplateIDs) + row.JetbrainsTemplateIds = uniqueSortedUUIDs(templates.JetBrainsTemplateIDs) + activeUserIDs := make(map[uuid.UUID]struct{}) + for _, insight := range insights { + activeUserIDs[insight.UserID] = struct{}{} + row.UsageTotalSeconds += int64(insight.UsageMins) * 60 + row.UsageSshSeconds += int64(insight.SSHMins) * 60 + row.UsageSftpSeconds += int64(insight.SFTPMins) * 60 + row.UsageReconnectingPtySeconds += int64(insight.ReconnectingPTYMins) * 60 + row.UsageVscodeSeconds += int64(insight.VSCodeMins) * 60 + row.UsageJetbrainsSeconds += int64(insight.JetBrainsMins) * 60 + } + row.ActiveUsers = int64(len(activeUserIDs)) + + return row, nil } func (q *FakeQuerier) GetTemplateInsightsByInterval(ctx context.Context, arg database.GetTemplateInsightsByIntervalParams) ([]database.GetTemplateInsightsByIntervalRow, error) { From 3651cc9cb3e869c73d9105911686df7937a57ec9 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Mon, 18 Mar 2024 20:27:21 +0200 Subject: [PATCH 10/19] feat(coderd/database): rewrite `GetTemplateInsightsByInterval` to use `template_usage_stats` --- coderd/database/queries.sql.go | 85 +++++++++------------------- coderd/database/queries/insights.sql | 81 +++++++++----------------- 2 files changed, 54 insertions(+), 112 deletions(-) diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 32d46abd9a7d5c..6d5d0993ec5585 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -2001,71 +2001,42 @@ func (q *sqlQuerier) GetTemplateInsights(ctx context.Context, arg GetTemplateIns } const getTemplateInsightsByInterval = `-- name: GetTemplateInsightsByInterval :many -WITH ts AS ( - SELECT - d::timestamptz AS from_, - CASE - WHEN (d::timestamptz + ($1::int || ' day')::interval) <= $2::timestamptz - THEN (d::timestamptz + ($1::int || ' day')::interval) - ELSE $2::timestamptz - END AS to_ - FROM - -- Subtract 1 microsecond from end_time to avoid including the next interval in the results. - generate_series($3::timestamptz, ($2::timestamptz) - '1 microsecond'::interval, ($1::int || ' day')::interval) AS d -), unflattened_usage_by_interval 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.template_id, - was.user_id - FROM ts - LEFT JOIN workspace_agent_stats was ON ( - was.created_at >= ts.from_ - AND was.created_at < ts.to_ - AND was.connection_count > 0 - AND CASE WHEN COALESCE(array_length($4::uuid[], 1), 0) > 0 THEN was.template_id = ANY($4::uuid[]) ELSE TRUE END - ) - GROUP BY ts.from_, ts.to_, was.template_id, was.user_id - - UNION ALL - - SELECT - 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($4::uuid[], 1), 0) > 0 THEN w.template_id = ANY($4::uuid[]) ELSE TRUE END +WITH + ts AS ( + SELECT + d::timestamptz AS from_, + CASE + WHEN (d::timestamptz + ($2::int || ' day')::interval) <= $3::timestamptz + THEN (d::timestamptz + ($2::int || ' day')::interval) + ELSE $3::timestamptz + END AS to_ + FROM + -- Subtract 1 microsecond from end_time to avoid including the next interval in the results. + generate_series($4::timestamptz, ($3::timestamptz) - '1 microsecond'::interval, ($2::int || ' day')::interval) AS d ) - GROUP BY ts.from_, ts.to_, w.template_id, was.user_id -) SELECT - from_ AS start_time, - to_ AS end_time, - array_remove(array_agg(DISTINCT template_id), NULL)::uuid[] AS template_ids, - COUNT(DISTINCT user_id) AS active_users -FROM unflattened_usage_by_interval -GROUP BY from_, to_ + ts.from_ AS start_time, + ts.to_ AS end_time, + array_remove(array_agg(DISTINCT tus.template_id), NULL)::uuid[] AS template_ids, + COUNT(DISTINCT tus.user_id) AS active_users +FROM + ts +LEFT JOIN + template_usage_stats AS tus +ON + tus.start_time >= ts.from_ + AND tus.end_time <= ts.to_ + AND CASE WHEN COALESCE(array_length($1::uuid[], 1), 0) > 0 THEN tus.template_id = ANY($1::uuid[]) ELSE TRUE END +GROUP BY + ts.from_, ts.to_ ` type GetTemplateInsightsByIntervalParams struct { + TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"` IntervalDays int32 `db:"interval_days" json:"interval_days"` 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"` } type GetTemplateInsightsByIntervalRow struct { @@ -2081,10 +2052,10 @@ type GetTemplateInsightsByIntervalRow struct { // interval/template, it will be included in the results with 0 active users. func (q *sqlQuerier) GetTemplateInsightsByInterval(ctx context.Context, arg GetTemplateInsightsByIntervalParams) ([]GetTemplateInsightsByIntervalRow, error) { rows, err := q.db.QueryContext(ctx, getTemplateInsightsByInterval, + pq.Array(arg.TemplateIDs), arg.IntervalDays, arg.EndTime, arg.StartTime, - pq.Array(arg.TemplateIDs), ) if err != nil { return nil, err diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index 28b9d7c94526ee..252570c01597d4 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -297,64 +297,35 @@ GROUP BY template_id, display_name, slug_or_port; -- time, if end time is a partial interval, it will be included in the results and -- that interval will be shorter than a full one. If there is no data for a selected -- interval/template, it will be included in the results with 0 active users. -WITH ts AS ( - SELECT - d::timestamptz AS from_, - CASE - WHEN (d::timestamptz + (@interval_days::int || ' day')::interval) <= @end_time::timestamptz - THEN (d::timestamptz + (@interval_days::int || ' day')::interval) - ELSE @end_time::timestamptz - END AS to_ - FROM - -- Subtract 1 microsecond from end_time to avoid including the next interval in the results. - generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 microsecond'::interval, (@interval_days::int || ' day')::interval) AS d -), unflattened_usage_by_interval 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.template_id, - was.user_id - FROM ts - LEFT JOIN workspace_agent_stats was ON ( - was.created_at >= ts.from_ - AND was.created_at < ts.to_ - 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.template_id, was.user_id - - UNION ALL - - SELECT - 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 +WITH + ts AS ( + SELECT + d::timestamptz AS from_, + CASE + WHEN (d::timestamptz + (@interval_days::int || ' day')::interval) <= @end_time::timestamptz + THEN (d::timestamptz + (@interval_days::int || ' day')::interval) + ELSE @end_time::timestamptz + END AS to_ + FROM + -- Subtract 1 microsecond from end_time to avoid including the next interval in the results. + generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 microsecond'::interval, (@interval_days::int || ' day')::interval) AS d ) - GROUP BY ts.from_, ts.to_, w.template_id, was.user_id -) SELECT - from_ AS start_time, - to_ AS end_time, - array_remove(array_agg(DISTINCT template_id), NULL)::uuid[] AS template_ids, - COUNT(DISTINCT user_id) AS active_users -FROM unflattened_usage_by_interval -GROUP BY from_, to_; + ts.from_ AS start_time, + ts.to_ AS end_time, + array_remove(array_agg(DISTINCT tus.template_id), NULL)::uuid[] AS template_ids, + COUNT(DISTINCT tus.user_id) AS active_users +FROM + ts +LEFT JOIN + template_usage_stats AS tus +ON + tus.start_time >= ts.from_ + AND tus.end_time <= ts.to_ + 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 + ts.from_, ts.to_; -- name: GetTemplateUsageStats :many SELECT From af551186f627ba6f41ab1acab387b9c654bb73d2 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 14:12:43 +0000 Subject: [PATCH 11/19] fix: implement `GetTemplateInsightsByInterval` in dbmem --- coderd/database/dbmem/dbmem.go | 135 +++++++++++++++++---------------- 1 file changed, 71 insertions(+), 64 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index 18401dfddaf2b2..6445aecd288c5b 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -3407,7 +3407,7 @@ func (q *FakeQuerier) GetTemplateInsights(_ context.Context, arg database.GetTem return row, nil } -func (q *FakeQuerier) GetTemplateInsightsByInterval(ctx context.Context, arg database.GetTemplateInsightsByIntervalParams) ([]database.GetTemplateInsightsByIntervalRow, error) { +func (q *FakeQuerier) GetTemplateInsightsByInterval(_ context.Context, arg database.GetTemplateInsightsByIntervalParams) ([]database.GetTemplateInsightsByIntervalRow, error) { err := validateDatabaseType(arg) if err != nil { return nil, err @@ -3416,82 +3416,89 @@ func (q *FakeQuerier) GetTemplateInsightsByInterval(ctx context.Context, arg dat q.mutex.RLock() defer q.mutex.RUnlock() - type statByInterval struct { - startTime, endTime time.Time - userSet map[uuid.UUID]struct{} - templateIDSet map[uuid.UUID]struct{} - } + /* + WITH + ts AS ( + SELECT + d::timestamptz AS from_, + CASE + WHEN (d::timestamptz + (@interval_days::int || ' day')::interval) <= @end_time::timestamptz + THEN (d::timestamptz + (@interval_days::int || ' day')::interval) + ELSE @end_time::timestamptz + END AS to_ + FROM + -- Subtract 1 microsecond from end_time to avoid including the next interval in the results. + generate_series(@start_time::timestamptz, (@end_time::timestamptz) - '1 microsecond'::interval, (@interval_days::int || ' day')::interval) AS d + ) - statsByInterval := []statByInterval{{arg.StartTime, arg.StartTime.AddDate(0, 0, int(arg.IntervalDays)), make(map[uuid.UUID]struct{}), make(map[uuid.UUID]struct{})}} - for statsByInterval[len(statsByInterval)-1].endTime.Before(arg.EndTime) { - statsByInterval = append(statsByInterval, statByInterval{statsByInterval[len(statsByInterval)-1].endTime, statsByInterval[len(statsByInterval)-1].endTime.AddDate(0, 0, int(arg.IntervalDays)), make(map[uuid.UUID]struct{}), make(map[uuid.UUID]struct{})}) - } - if statsByInterval[len(statsByInterval)-1].endTime.After(arg.EndTime) { - statsByInterval[len(statsByInterval)-1].endTime = arg.EndTime - } + SELECT + ts.from_ AS start_time, + ts.to_ AS end_time, + array_remove(array_agg(DISTINCT tus.template_id), NULL)::uuid[] AS template_ids, + COUNT(DISTINCT tus.user_id) AS active_users + FROM + ts + LEFT JOIN + template_usage_stats AS tus + ON + tus.start_time >= ts.from_ + AND tus.end_time <= ts.to_ + 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 + ts.from_, ts.to_; + */ - for _, s := range q.workspaceAgentStats { - if s.CreatedAt.Before(arg.StartTime) || s.CreatedAt.Equal(arg.EndTime) || s.CreatedAt.After(arg.EndTime) { - continue - } - if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, s.TemplateID) { - continue - } - if s.ConnectionCount == 0 { - continue + type interval struct { + From time.Time + To time.Time + } + var ts []interval + for d := arg.StartTime; d.Before(arg.EndTime); d = d.AddDate(0, 0, int(arg.IntervalDays)) { + to := d.AddDate(0, 0, int(arg.IntervalDays)) + if to.After(arg.EndTime) { + to = arg.EndTime } + ts = append(ts, interval{From: d, To: to}) + } - for _, ds := range statsByInterval { - if s.CreatedAt.Before(ds.startTime) || s.CreatedAt.Equal(ds.endTime) || s.CreatedAt.After(ds.endTime) { + type grouped struct { + TemplateIDs map[uuid.UUID]struct{} + UserIDs map[uuid.UUID]struct{} + } + groupedByInterval := make(map[interval]grouped) + for _, tus := range q.templateUsageStats { + for _, t := range ts { + if tus.StartTime.Before(t.From) || tus.EndTime.After(t.To) { continue } - ds.userSet[s.UserID] = struct{}{} - ds.templateIDSet[s.TemplateID] = struct{}{} - } - } - - for _, s := range q.workspaceAppStats { - w, err := q.getWorkspaceByIDNoLock(ctx, s.WorkspaceID) - if err != nil { - return nil, err - } - - if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, w.TemplateID) { - continue - } - - for _, ds := range statsByInterval { - // (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(ds.startTime) || s.SessionStartedAt.Equal(ds.startTime)) && s.SessionStartedAt.Before(ds.endTime)) || - (s.SessionEndedAt.After(ds.startTime) && s.SessionEndedAt.Before(ds.endTime)) || - (s.SessionStartedAt.Before(ds.startTime) && (s.SessionEndedAt.After(ds.endTime) || s.SessionEndedAt.Equal(ds.endTime)))) { + if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, tus.TemplateID) { continue } - - ds.userSet[s.UserID] = struct{}{} - ds.templateIDSet[w.TemplateID] = struct{}{} + g, ok := groupedByInterval[t] + if !ok { + g = grouped{ + TemplateIDs: make(map[uuid.UUID]struct{}), + UserIDs: make(map[uuid.UUID]struct{}), + } + } + g.TemplateIDs[tus.TemplateID] = struct{}{} + g.UserIDs[tus.UserID] = struct{}{} + groupedByInterval[t] = g } } - var result []database.GetTemplateInsightsByIntervalRow - for _, ds := range statsByInterval { - templateIDs := make([]uuid.UUID, 0, len(ds.templateIDSet)) - for templateID := range ds.templateIDSet { - templateIDs = append(templateIDs, templateID) + var rows []database.GetTemplateInsightsByIntervalRow + for _, t := range ts { // Ordered by interval. + row := database.GetTemplateInsightsByIntervalRow{ + StartTime: t.From, + EndTime: t.To, } - slices.SortFunc(templateIDs, func(a, b uuid.UUID) int { - return slice.Ascending(a.String(), b.String()) - }) - result = append(result, database.GetTemplateInsightsByIntervalRow{ - StartTime: ds.startTime, - EndTime: ds.endTime, - TemplateIDs: templateIDs, - ActiveUsers: int64(len(ds.userSet)), - }) + row.TemplateIDs = uniqueSortedUUIDs(maps.Keys(groupedByInterval[t].TemplateIDs)) + row.ActiveUsers = int64(len(groupedByInterval[t].UserIDs)) + rows = append(rows, row) } - return result, nil + + return rows, nil } func (q *FakeQuerier) GetTemplateInsightsByTemplate(_ context.Context, arg database.GetTemplateInsightsByTemplateParams) ([]database.GetTemplateInsightsByTemplateRow, error) { From e5da3931d91c103fa6fb928f507d7eecb9a35a6e Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Mon, 18 Mar 2024 20:27:21 +0200 Subject: [PATCH 12/19] feat(coderd/database): rewrite `GetTemplateInsightsByTemplate` to use `template_usage_stats` --- coderd/database/queries.sql.go | 47 ++++++++++++---------------- coderd/database/queries/insights.sql | 35 +++++++-------------- 2 files changed, 32 insertions(+), 50 deletions(-) diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 6d5d0993ec5585..7a17ac20fd8cb0 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -2084,31 +2084,20 @@ func (q *sqlQuerier) GetTemplateInsightsByInterval(ctx context.Context, arg GetT } const getTemplateInsightsByTemplate = `-- name: GetTemplateInsightsByTemplate :many -WITH agent_stats_by_interval_and_user AS ( - SELECT - date_trunc('minute', was.created_at) AS created_at_trunc, - was.template_id, - was.user_id, - CASE WHEN SUM(was.session_count_vscode) > 0 THEN 60 ELSE 0 END AS usage_vscode_seconds, - CASE WHEN SUM(was.session_count_jetbrains) > 0 THEN 60 ELSE 0 END AS usage_jetbrains_seconds, - CASE WHEN SUM(was.session_count_reconnecting_pty) > 0 THEN 60 ELSE 0 END AS usage_reconnecting_pty_seconds, - CASE WHEN SUM(was.session_count_ssh) > 0 THEN 60 ELSE 0 END AS usage_ssh_seconds - FROM workspace_agent_stats was - WHERE - was.created_at >= $1::timestamptz - AND was.created_at < $2::timestamptz - AND was.connection_count > 0 - GROUP BY created_at_trunc, was.template_id, was.user_id -) - SELECT template_id, - COALESCE(COUNT(DISTINCT user_id))::bigint AS active_users, - 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 agent_stats_by_interval_and_user + COUNT(DISTINCT user_id) AS active_users, + (SUM(usage_mins) * 60)::bigint AS usage_total_seconds, -- Includes app usage. + (SUM(ssh_mins) * 60)::bigint AS usage_ssh_seconds, + (SUM(sftp_mins) * 60)::bigint AS usage_sftp_seconds, + (SUM(reconnecting_pty_mins) * 60)::bigint AS usage_reconnecting_pty_seconds, + (SUM(vscode_mins) * 60)::bigint AS usage_vscode_seconds, + (SUM(jetbrains_mins) * 60)::bigint AS usage_jetbrains_seconds +FROM + template_usage_stats +WHERE + start_time >= $1::timestamptz + AND end_time <= $2::timestamptz GROUP BY template_id ` @@ -2120,10 +2109,12 @@ type GetTemplateInsightsByTemplateParams struct { type GetTemplateInsightsByTemplateRow struct { TemplateID uuid.UUID `db:"template_id" json:"template_id"` ActiveUsers int64 `db:"active_users" json:"active_users"` + UsageTotalSeconds int64 `db:"usage_total_seconds" json:"usage_total_seconds"` + UsageSshSeconds int64 `db:"usage_ssh_seconds" json:"usage_ssh_seconds"` + UsageSftpSeconds int64 `db:"usage_sftp_seconds" json:"usage_sftp_seconds"` + UsageReconnectingPtySeconds int64 `db:"usage_reconnecting_pty_seconds" json:"usage_reconnecting_pty_seconds"` 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"` - UsageSshSeconds int64 `db:"usage_ssh_seconds" json:"usage_ssh_seconds"` } func (q *sqlQuerier) GetTemplateInsightsByTemplate(ctx context.Context, arg GetTemplateInsightsByTemplateParams) ([]GetTemplateInsightsByTemplateRow, error) { @@ -2138,10 +2129,12 @@ func (q *sqlQuerier) GetTemplateInsightsByTemplate(ctx context.Context, arg GetT if err := rows.Scan( &i.TemplateID, &i.ActiveUsers, + &i.UsageTotalSeconds, + &i.UsageSshSeconds, + &i.UsageSftpSeconds, + &i.UsageReconnectingPtySeconds, &i.UsageVscodeSeconds, &i.UsageJetbrainsSeconds, - &i.UsageReconnectingPtySeconds, - &i.UsageSshSeconds, ); err != nil { return nil, err } diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index 252570c01597d4..592c3429282724 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -162,31 +162,20 @@ FROM insights; -- name: GetTemplateInsightsByTemplate :many -WITH agent_stats_by_interval_and_user AS ( - SELECT - date_trunc('minute', was.created_at) AS created_at_trunc, - was.template_id, - was.user_id, - CASE WHEN SUM(was.session_count_vscode) > 0 THEN 60 ELSE 0 END AS usage_vscode_seconds, - CASE WHEN SUM(was.session_count_jetbrains) > 0 THEN 60 ELSE 0 END AS usage_jetbrains_seconds, - CASE WHEN SUM(was.session_count_reconnecting_pty) > 0 THEN 60 ELSE 0 END AS usage_reconnecting_pty_seconds, - CASE WHEN SUM(was.session_count_ssh) > 0 THEN 60 ELSE 0 END AS usage_ssh_seconds - FROM workspace_agent_stats was - WHERE - was.created_at >= @start_time::timestamptz - AND was.created_at < @end_time::timestamptz - AND was.connection_count > 0 - GROUP BY created_at_trunc, was.template_id, was.user_id -) - SELECT template_id, - COALESCE(COUNT(DISTINCT user_id))::bigint AS active_users, - 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 agent_stats_by_interval_and_user + COUNT(DISTINCT user_id) AS active_users, + (SUM(usage_mins) * 60)::bigint AS usage_total_seconds, -- Includes app usage. + (SUM(ssh_mins) * 60)::bigint AS usage_ssh_seconds, + (SUM(sftp_mins) * 60)::bigint AS usage_sftp_seconds, + (SUM(reconnecting_pty_mins) * 60)::bigint AS usage_reconnecting_pty_seconds, + (SUM(vscode_mins) * 60)::bigint AS usage_vscode_seconds, + (SUM(jetbrains_mins) * 60)::bigint AS usage_jetbrains_seconds +FROM + template_usage_stats +WHERE + start_time >= @start_time::timestamptz + AND end_time <= @end_time::timestamptz GROUP BY template_id; -- name: GetTemplateAppInsights :many From a234c5d62cd60b84f2e020812f658070b4221fe0 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 14:22:17 +0000 Subject: [PATCH 13/19] fix: implement `GetTemplateInsightsByTemplate` in dbmem --- coderd/database/dbmem/dbmem.go | 123 +++++++++++++-------------------- 1 file changed, 47 insertions(+), 76 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index 6445aecd288c5b..c6a0edfe0a3a67 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -3510,90 +3510,61 @@ func (q *FakeQuerier) GetTemplateInsightsByTemplate(_ context.Context, arg datab q.mutex.RLock() defer q.mutex.RUnlock() - // map time.Time x TemplateID x UserID x - appUsageByTemplateAndUser := map[time.Time]map[uuid.UUID]map[uuid.UUID]database.GetTemplateInsightsByTemplateRow{} - - // Review agent stats in terms of usage - templateIDSet := make(map[uuid.UUID]struct{}) + /* + SELECT + template_id, + COUNT(DISTINCT user_id) AS active_users, + (SUM(usage_mins) * 60)::bigint AS usage_total_seconds, -- Includes app usage. + (SUM(ssh_mins) * 60)::bigint AS usage_ssh_seconds, + (SUM(sftp_mins) * 60)::bigint AS usage_sftp_seconds, + (SUM(reconnecting_pty_mins) * 60)::bigint AS usage_reconnecting_pty_seconds, + (SUM(vscode_mins) * 60)::bigint AS usage_vscode_seconds, + (SUM(jetbrains_mins) * 60)::bigint AS usage_jetbrains_seconds + FROM + template_usage_stats + WHERE + start_time >= @start_time::timestamptz + AND end_time <= @end_time::timestamptz + GROUP BY template_id; + */ - for _, s := range q.workspaceAgentStats { - if s.CreatedAt.Before(arg.StartTime) || s.CreatedAt.Equal(arg.EndTime) || s.CreatedAt.After(arg.EndTime) { - continue - } - if s.ConnectionCount == 0 { + type grouped struct { + database.GetTemplateInsightsByTemplateRow + activeUserIDs map[uuid.UUID]struct{} + } + groupedByTemplateID := make(map[uuid.UUID]grouped) + for _, tus := range q.templateUsageStats { + if tus.StartTime.Before(arg.StartTime) || tus.EndTime.After(arg.EndTime) { continue } - - t := s.CreatedAt.Truncate(time.Minute) - templateIDSet[s.TemplateID] = struct{}{} - - if _, ok := appUsageByTemplateAndUser[t]; !ok { - appUsageByTemplateAndUser[t] = make(map[uuid.UUID]map[uuid.UUID]database.GetTemplateInsightsByTemplateRow) - } - - if _, ok := appUsageByTemplateAndUser[t][s.TemplateID]; !ok { - appUsageByTemplateAndUser[t][s.TemplateID] = make(map[uuid.UUID]database.GetTemplateInsightsByTemplateRow) - } - - if _, ok := appUsageByTemplateAndUser[t][s.TemplateID][s.UserID]; !ok { - appUsageByTemplateAndUser[t][s.TemplateID][s.UserID] = database.GetTemplateInsightsByTemplateRow{} - } - - u := appUsageByTemplateAndUser[t][s.TemplateID][s.UserID] - if s.SessionCountJetBrains > 0 { - u.UsageJetbrainsSeconds = 60 - } - if s.SessionCountVSCode > 0 { - u.UsageVscodeSeconds = 60 - } - if s.SessionCountReconnectingPTY > 0 { - u.UsageReconnectingPtySeconds = 60 - } - if s.SessionCountSSH > 0 { - u.UsageSshSeconds = 60 + row, ok := groupedByTemplateID[tus.TemplateID] + if !ok { + row = grouped{ + GetTemplateInsightsByTemplateRow: database.GetTemplateInsightsByTemplateRow{ + TemplateID: tus.TemplateID, + }, + activeUserIDs: make(map[uuid.UUID]struct{}), + } } - appUsageByTemplateAndUser[t][s.TemplateID][s.UserID] = u + row.activeUserIDs[tus.UserID] = struct{}{} + row.ActiveUsers = int64(len(row.activeUserIDs)) + row.UsageTotalSeconds += int64(tus.UsageMins) * 60 + row.UsageSshSeconds += int64(tus.SshMins) * 60 + row.UsageSftpSeconds += int64(tus.SftpMins) * 60 + row.UsageReconnectingPtySeconds += int64(tus.ReconnectingPtyMins) * 60 + row.UsageVscodeSeconds += int64(tus.VscodeMins) * 60 + row.UsageJetbrainsSeconds += int64(tus.JetbrainsMins) * 60 + groupedByTemplateID[tus.TemplateID] = row } - // Sort used templates - templateIDs := make([]uuid.UUID, 0, len(templateIDSet)) - for templateID := range templateIDSet { - templateIDs = append(templateIDs, templateID) + var rows []database.GetTemplateInsightsByTemplateRow + for _, row := range groupedByTemplateID { + rows = append(rows, row.GetTemplateInsightsByTemplateRow) } - slices.SortFunc(templateIDs, func(a, b uuid.UUID) int { - return slice.Ascending(a.String(), b.String()) + slices.SortFunc(rows, func(a, b database.GetTemplateInsightsByTemplateRow) int { + return slice.Ascending(a.TemplateID.String(), b.TemplateID.String()) }) - - // Build result - var result []database.GetTemplateInsightsByTemplateRow - for _, templateID := range templateIDs { - r := database.GetTemplateInsightsByTemplateRow{ - TemplateID: templateID, - } - - uniqueUsers := map[uuid.UUID]struct{}{} - - for _, mTemplateUserUsage := range appUsageByTemplateAndUser { - mUserUsage, ok := mTemplateUserUsage[templateID] - if !ok { - continue // template was not used in this time window - } - - for userID, usage := range mUserUsage { - uniqueUsers[userID] = struct{}{} - - r.UsageJetbrainsSeconds += usage.UsageJetbrainsSeconds - r.UsageVscodeSeconds += usage.UsageVscodeSeconds - r.UsageReconnectingPtySeconds += usage.UsageReconnectingPtySeconds - r.UsageSshSeconds += usage.UsageSshSeconds - } - } - - r.ActiveUsers = int64(len(uniqueUsers)) - - result = append(result, r) - } - return result, nil + return rows, nil } func (q *FakeQuerier) GetTemplateParameterInsights(ctx context.Context, arg database.GetTemplateParameterInsightsParams) ([]database.GetTemplateParameterInsightsRow, error) { From 23f382c0ca9dfb401b9dadd8560b50826ea70376 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Mon, 18 Mar 2024 20:27:21 +0200 Subject: [PATCH 14/19] feat(coderd/database): rewrite `GetTemplateAppInsights` to use `template_usage_stats` --- coderd/database/dbmem/dbmem.go | 4 +- coderd/database/queries.sql.go | 152 +++++++++++++++++---------- coderd/database/queries/insights.sql | 132 ++++++++++++++--------- coderd/insights.go | 12 +-- 4 files changed, 186 insertions(+), 114 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index c6a0edfe0a3a67..526ab6ee1d3cd5 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -3000,8 +3000,8 @@ func (q *FakeQuerier) GetTemplateAppInsights(ctx context.Context, arg database.G 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 != ""}, + DisplayName: appKey.DisplayName, + Icon: appKey.Icon, IsApp: appKey.Slug != "", UsageSeconds: usage, }) diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 7a17ac20fd8cb0..339075405e0fbf 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -1698,81 +1698,117 @@ func (q *sqlQuerier) UpdateGroupByID(ctx context.Context, arg UpdateGroupByIDPar } const getTemplateAppInsights = `-- name: GetTemplateAppInsights :many -WITH app_stats_by_user_and_agent AS ( - SELECT - s.start_time, - 60 as 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 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 - ) - -- 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 +WITH + app_insights AS ( + SELECT + tus.user_id, + array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids, + app_usage.key::text AS app_name, + COALESCE(wa.display_name, '') AS display_name, + 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 >= $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 ) - -- 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 - 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 + t.template_ids, + array_agg(DISTINCT ai.user_id)::uuid[] AS active_user_ids, + ''::text AS access_method, -- TODO(mafredri): Remove. + 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 GetTemplateAppInsightsParams 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"` + 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"` + 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 string `db:"display_name" json:"display_name"` + Icon string `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, 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 { return nil, err } diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index 592c3429282724..bafd56dad8b193 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -182,57 +182,93 @@ GROUP BY template_id; -- 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 app_stats_by_user_and_agent AS ( - SELECT - s.start_time, - 60 as 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 workspace_app_stats was - 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 +WITH + app_insights AS ( + SELECT + tus.user_id, + array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids, + app_usage.key::text AS app_name, + COALESCE(wa.display_name, '') AS display_name, + 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 + ), + 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 ) - -- 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 - 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; + t.template_ids, + array_agg(DISTINCT ai.user_id)::uuid[] AS active_user_ids, + ''::text AS access_method, -- TODO(mafredri): Remove. + 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; -- name: GetTemplateAppInsightsByTemplate :many WITH app_stats_by_user_and_agent AS ( diff --git a/coderd/insights.go b/coderd/insights.go index b38e7aecdeb026..630cdaf9b7f5a7 100644 --- a/coderd/insights.go +++ b/coderd/insights.go @@ -474,11 +474,11 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage if a.SlugOrPort != b.SlugOrPort { return strings.Compare(a.SlugOrPort, b.SlugOrPort) } - if a.DisplayName.String != b.DisplayName.String { - return strings.Compare(a.DisplayName.String, b.DisplayName.String) + if a.DisplayName != b.DisplayName { + return strings.Compare(a.DisplayName, b.DisplayName) } - if a.Icon.String != b.Icon.String { - return strings.Compare(a.Icon.String, b.Icon.String) + if a.Icon != b.Icon { + return strings.Compare(a.Icon, b.Icon) } if !a.IsApp && b.IsApp { return -1 @@ -496,9 +496,9 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage apps = append(apps, codersdk.TemplateAppUsage{ TemplateIDs: app.TemplateIDs, Type: codersdk.TemplateAppsTypeApp, - DisplayName: app.DisplayName.String, + DisplayName: app.DisplayName, Slug: app.SlugOrPort, - Icon: app.Icon.String, + Icon: app.Icon, Seconds: app.UsageSeconds, }) } From fcaaff8686dd335d434445d1d3147590818ed1d5 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 15:26:53 +0000 Subject: [PATCH 15/19] simplify query --- coderd/database/queries.sql.go | 21 +++++++++------------ coderd/database/queries/insights.sql | 3 +-- coderd/insights.go | 3 --- 3 files changed, 10 insertions(+), 17 deletions(-) diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 339075405e0fbf..56148cc76627a1 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -1767,8 +1767,7 @@ WITH SELECT t.template_ids, - array_agg(DISTINCT ai.user_id)::uuid[] AS active_user_ids, - ''::text AS access_method, -- TODO(mafredri): Remove. + COUNT(DISTINCT ai.user_id) AS active_users, ai.app_name AS slug_or_port, ai.display_name, ai.icon, @@ -1794,14 +1793,13 @@ type GetTemplateAppInsightsParams struct { } 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 string `db:"display_name" json:"display_name"` - Icon string `db:"icon" json:"icon"` - IsApp bool `db:"is_app" json:"is_app"` - UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"` + TemplateIDs []uuid.UUID `db:"template_ids" json:"template_ids"` + ActiveUsers int64 `db:"active_users" json:"active_users"` + SlugOrPort string `db:"slug_or_port" json:"slug_or_port"` + DisplayName string `db:"display_name" json:"display_name"` + Icon string `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 @@ -1818,8 +1816,7 @@ func (q *sqlQuerier) GetTemplateAppInsights(ctx context.Context, arg GetTemplate var i GetTemplateAppInsightsRow if err := rows.Scan( pq.Array(&i.TemplateIDs), - pq.Array(&i.ActiveUserIDs), - &i.AccessMethod, + &i.ActiveUsers, &i.SlugOrPort, &i.DisplayName, &i.Icon, diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index bafd56dad8b193..a0729d20174a93 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -251,8 +251,7 @@ WITH SELECT t.template_ids, - array_agg(DISTINCT ai.user_id)::uuid[] AS active_user_ids, - ''::text AS access_method, -- TODO(mafredri): Remove. + COUNT(DISTINCT ai.user_id) AS active_users, ai.app_name AS slug_or_port, ai.display_name, ai.icon, diff --git a/coderd/insights.go b/coderd/insights.go index 630cdaf9b7f5a7..7231cb2f5d5161 100644 --- a/coderd/insights.go +++ b/coderd/insights.go @@ -468,9 +468,6 @@ func convertTemplateInsightsApps(usage database.GetTemplateInsightsRow, appUsage // // ORDER BY access_method, slug_or_port, display_name, icon, is_app 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 { return strings.Compare(a.SlugOrPort, b.SlugOrPort) } From ce9890e313804a47f8ad8e80ad7a8ef89c5bc527 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 15:49:19 +0000 Subject: [PATCH 16/19] fix: implement `GetTemplateAppInsights` in dbmem --- coderd/database/dbmem/dbmem.go | 361 ++++++++++++++++++++------- coderd/database/queries.sql.go | 1 + coderd/database/queries/insights.sql | 1 + 3 files changed, 273 insertions(+), 90 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index 526ab6ee1d3cd5..bc444ab28fb3b5 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -799,6 +799,92 @@ func least[T constraints.Ordered](a, b T) T { 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 { return xerrors.New("AcquireLock must only be called within a transaction") } @@ -2896,119 +2982,214 @@ func (q *FakeQuerier) GetTemplateAppInsights(ctx context.Context, arg database.G q.mutex.RLock() defer q.mutex.RUnlock() - type appKey struct { - AccessMethod string - SlugOrPort string - Slug string - DisplayName string - Icon string + /* + WITH + */ + + /* + app_insights AS ( + SELECT + tus.user_id, + array_agg(DISTINCT tus.template_id)::uuid[] AS template_ids, + app_usage.key::text AS app_name, + COALESCE(wa.display_name, '') AS display_name, + 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 uniqueKey struct { - TemplateID uuid.UUID - UserID uuid.UUID - AgentID uuid.UUID - AppKey appKey + type appInsightsRow struct { + appInsightsGroupBy + TemplateIDs []uuid.UUID + AppUsageMins int64 } - - 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)))) { + appInsightRows := make(map[appInsightsGroupBy]appInsightsRow) + // FROM + for _, stat := range q.templateUsageStats { + // WHERE + if stat.StartTime.Before(arg.StartTime) || stat.StartTime.After(arg.EndTime) { continue } - - w, err := q.getWorkspaceByIDNoLock(ctx, s.WorkspaceID) - if err != nil { - return nil, err - } - - if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, w.TemplateID) { + if len(arg.TemplateIDs) > 0 && !slices.Contains(arg.TemplateIDs, stat.TemplateID) { continue } - app, _ := q.getWorkspaceAppByAgentIDAndSlugNoLock(ctx, database.GetWorkspaceAppByAgentIDAndSlugParams{ - AgentID: s.AgentID, - Slug: s.SlugOrPort, - }) + // json_each + for appName, appUsage := range stat.AppUsageMins { + // LEFT JOIN LATERAL + app, _ := q.getLatestWorkspaceAppByTemplateIDUserIDSlugNoLock(ctx, stat.TemplateID, stat.UserID, appName) - 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) + // SELECT + key := appInsightsGroupBy{ + StartTime: stat.StartTime, + UserID: stat.UserID, + AppName: appName, + DisplayName: app.DisplayName, + Icon: app.Icon, + IsApp: app.Slug != "", + } + row, ok := appInsightRows[key] + if !ok { + row = appInsightsRow{ + appInsightsGroupBy: key, + } + } + row.TemplateIDs = append(row.TemplateIDs, stat.TemplateID) + row.AppUsageMins = least(row.AppUsageMins+appUsage, 30) + appInsightRows[key] = row } + } - 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) - } + /* + 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 + ) + */ + + type appGroupBy struct { + AppName string + DisplayName string + Icon string + IsApp bool + } + type templateRow struct { + appGroupBy + TemplateIDs []uuid.UUID } - 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{}) + templateRows := make(map[appGroupBy]templateRow) + for _, row := range appInsightRows { + key := appGroupBy{ + AppName: row.AppName, + DisplayName: row.DisplayName, + Icon: row.Icon, + IsApp: row.IsApp, + } + row, ok := templateRows[key] + if !ok { + row = templateRow{ + appGroupBy: key, } - appUsageUserIDs[uniqueKey.AppKey][uniqueKey.UserID] = struct{}{} - appUsage[uniqueKey.AppKey] += seconds } + row.TemplateIDs = append(row.TemplateIDs, row.TemplateIDs...) + templateRows[key] = row } - 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) + /* + 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, } - slices.SortFunc(activeUserIDs, func(a, b uuid.UUID) int { - return slice.Ascending(a.String(), b.String()) - }) + row := groupedRows[key] + row.TemplateIDs = append(row.TemplateIDs, aiRow.TemplateIDs...) + row.ActiveUserIDs = append(row.ActiveUserIDs, aiRow.UserID) + row.UsageSeconds += aiRow.AppUsageMins * 60 + } + var rows []database.GetTemplateAppInsightsRow + for k, gr := range groupedRows { rows = append(rows, database.GetTemplateAppInsightsRow{ - TemplateIDs: templateIDs, - ActiveUserIDs: activeUserIDs, - AccessMethod: appKey.AccessMethod, - SlugOrPort: appKey.SlugOrPort, - DisplayName: appKey.DisplayName, - Icon: appKey.Icon, - IsApp: appKey.Slug != "", - UsageSeconds: usage, + TemplateIDs: uniqueSortedUUIDs(gr.TemplateIDs), + ActiveUsers: int64(len(uniqueSortedUUIDs(gr.ActiveUserIDs))), + DisplayName: k.DisplayName, + SlugOrPort: k.AppName, + UsageSeconds: gr.UsageSeconds, }) } // 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 } diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 56148cc76627a1..65393e3874f98c 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -1707,6 +1707,7 @@ WITH COALESCE(wa.display_name, '') AS display_name, COALESCE(wa.icon, '') AS icon, (wa.slug IS NOT NULL)::boolean AS is_app, + -- See motivation in GetTemplateInsights for LEAST(SUM(n), 30). 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 diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index a0729d20174a93..5d460ec8b85453 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -191,6 +191,7 @@ WITH COALESCE(wa.display_name, '') AS display_name, COALESCE(wa.icon, '') AS icon, (wa.slug IS NOT NULL)::boolean AS is_app, + -- See motivation in GetTemplateInsights for LEAST(SUM(n), 30). 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 From 460c244cfce2ac482098c873ba3162fdae9741f6 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 16:13:50 +0000 Subject: [PATCH 17/19] update join comment --- coderd/database/queries.sql.go | 4 +++- coderd/database/queries/insights.sql | 4 +++- 2 files changed, 6 insertions(+), 2 deletions(-) diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 65393e3874f98c..2e155986ad3bc9 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -1712,7 +1712,9 @@ WITH 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. + -- The joins in this query are necessary to associate an app with a + -- template, we use this to get the app metadata like display name + -- and icon. SELECT app.display_name, app.icon, diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index 5d460ec8b85453..0cc9f3356d9d48 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -196,7 +196,9 @@ WITH 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. + -- The joins in this query are necessary to associate an app with a + -- template, we use this to get the app metadata like display name + -- and icon. SELECT app.display_name, app.icon, From af3fc3ed700856d871d4ba5c2368c6f817200e52 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Mon, 18 Mar 2024 20:27:21 +0200 Subject: [PATCH 18/19] feat(coderd/database): rewrite `GetTemplateAppInsightsByTemplate` to use `template_usage_stats` --- coderd/database/dbmem/dbmem.go | 2 +- coderd/database/queries.sql.go | 103 +++++++++--------- coderd/database/queries/insights.sql | 89 +++++++-------- .../insights/metricscollector.go | 2 +- 4 files changed, 101 insertions(+), 95 deletions(-) diff --git a/coderd/database/dbmem/dbmem.go b/coderd/database/dbmem/dbmem.go index bc444ab28fb3b5..3a14301a5a492c 100644 --- a/coderd/database/dbmem/dbmem.go +++ b/coderd/database/dbmem/dbmem.go @@ -3279,7 +3279,7 @@ func (q *FakeQuerier) GetTemplateAppInsightsByTemplate(ctx context.Context, arg for _, usageKey := range usageKeys { r := database.GetTemplateAppInsightsByTemplateRow{ TemplateID: usageKey.TemplateID, - DisplayName: sql.NullString{String: usageKey.DisplayName, Valid: true}, + DisplayName: usageKey.DisplayName, SlugOrPort: usageKey.Slug, } for _, mUserUsage := range usageByTemplateAppUser[usageKey] { diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index 2e155986ad3bc9..b1dd8eb75d795a 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -1840,51 +1840,54 @@ func (q *sqlQuerier) GetTemplateAppInsights(ctx context.Context, arg GetTemplate } const getTemplateAppInsightsByTemplate = `-- name: GetTemplateAppInsightsByTemplate :many -WITH app_stats_by_user_and_agent AS ( +SELECT + tus.template_id, + COUNT(DISTINCT tus.user_id) AS active_users, + app_usage.key::text AS slug_or_port, + COALESCE(wa.display_name, '') AS display_name, + (SUM(app_usage.value::int) * 60)::bigint AS usage_seconds +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 - s.start_time, - 60 as seconds, - w.template_id, - was.user_id, - was.agent_id, - was.slug_or_port, - wa.display_name, - (wa.slug IS NOT NULL)::boolean AS is_app - FROM workspace_app_stats was - JOIN workspaces w ON ( - w.id = was.workspace_id - ) - -- 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) + app.display_name, + 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 - s.start_time >= $1::timestamptz - -- Subtract one minute because the series only contains the start time. - AND s.start_time < ($2::timestamptz) - '1 minute'::interval - GROUP BY s.start_time, w.template_id, was.user_id, was.agent_id, was.slug_or_port, wa.display_name, wa.slug -) - -SELECT - template_id, - display_name, - slug_or_port, - COALESCE(COUNT(DISTINCT user_id))::bigint AS active_users, - SUM(seconds) AS usage_seconds -FROM app_stats_by_user_and_agent -WHERE is_app IS TRUE -GROUP BY template_id, display_name, slug_or_port + -- 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 +) wa +ON + true +WHERE + tus.start_time >= $1::timestamptz + AND tus.end_time <= $2::timestamptz + AND wa.slug IS NOT NULL -- Check is_app. +GROUP BY + tus.template_id, app_usage.key::text, wa.display_name ` type GetTemplateAppInsightsByTemplateParams struct { @@ -1893,11 +1896,11 @@ type GetTemplateAppInsightsByTemplateParams struct { } type GetTemplateAppInsightsByTemplateRow struct { - TemplateID uuid.UUID `db:"template_id" json:"template_id"` - DisplayName sql.NullString `db:"display_name" json:"display_name"` - SlugOrPort string `db:"slug_or_port" json:"slug_or_port"` - ActiveUsers int64 `db:"active_users" json:"active_users"` - UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"` + TemplateID uuid.UUID `db:"template_id" json:"template_id"` + ActiveUsers int64 `db:"active_users" json:"active_users"` + SlugOrPort string `db:"slug_or_port" json:"slug_or_port"` + DisplayName string `db:"display_name" json:"display_name"` + UsageSeconds int64 `db:"usage_seconds" json:"usage_seconds"` } func (q *sqlQuerier) GetTemplateAppInsightsByTemplate(ctx context.Context, arg GetTemplateAppInsightsByTemplateParams) ([]GetTemplateAppInsightsByTemplateRow, error) { @@ -1911,9 +1914,9 @@ func (q *sqlQuerier) GetTemplateAppInsightsByTemplate(ctx context.Context, arg G var i GetTemplateAppInsightsByTemplateRow if err := rows.Scan( &i.TemplateID, - &i.DisplayName, - &i.SlugOrPort, &i.ActiveUsers, + &i.SlugOrPort, + &i.DisplayName, &i.UsageSeconds, ); err != nil { return nil, err diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index 0cc9f3356d9d48..0877523898a1e1 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -273,51 +273,54 @@ GROUP BY t.template_ids, ai.app_name, ai.display_name, ai.icon, ai.is_app; -- name: GetTemplateAppInsightsByTemplate :many -WITH app_stats_by_user_and_agent AS ( +SELECT + tus.template_id, + COUNT(DISTINCT tus.user_id) AS active_users, + app_usage.key::text AS slug_or_port, + COALESCE(wa.display_name, '') AS display_name, + (SUM(app_usage.value::int) * 60)::bigint AS usage_seconds +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 - s.start_time, - 60 as seconds, - w.template_id, - was.user_id, - was.agent_id, - was.slug_or_port, - wa.display_name, - (wa.slug IS NOT NULL)::boolean AS is_app - FROM workspace_app_stats was - JOIN workspaces w ON ( - w.id = was.workspace_id - ) - -- 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) + app.display_name, + 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 - 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.slug_or_port, wa.display_name, wa.slug -) - -SELECT - template_id, - display_name, - slug_or_port, - COALESCE(COUNT(DISTINCT user_id))::bigint AS active_users, - SUM(seconds) AS usage_seconds -FROM app_stats_by_user_and_agent -WHERE is_app IS TRUE -GROUP BY template_id, display_name, slug_or_port; + -- 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 +) wa +ON + true +WHERE + tus.start_time >= @start_time::timestamptz + AND tus.end_time <= @end_time::timestamptz + AND wa.slug IS NOT NULL -- Check is_app. +GROUP BY + tus.template_id, app_usage.key::text, wa.display_name; -- name: GetTemplateInsightsByInterval :many -- GetTemplateInsightsByInterval returns all intervals between start and end diff --git a/coderd/prometheusmetrics/insights/metricscollector.go b/coderd/prometheusmetrics/insights/metricscollector.go index 1534d09cd457a4..7dcf6025f2fa28 100644 --- a/coderd/prometheusmetrics/insights/metricscollector.go +++ b/coderd/prometheusmetrics/insights/metricscollector.go @@ -194,7 +194,7 @@ func (mc *MetricsCollector) Collect(metricsCh chan<- prometheus.Metric) { // Custom apps for _, appRow := range data.apps { metricsCh <- prometheus.MustNewConstMetric(applicationsUsageSecondsDesc, prometheus.GaugeValue, float64(appRow.UsageSeconds), data.templateNames[appRow.TemplateID], - appRow.DisplayName.String, appRow.SlugOrPort) + appRow.DisplayName, appRow.SlugOrPort) } // Built-in apps From b11b3b6b89f65fd7968a71e0e48ab8c24e4252c0 Mon Sep 17 00:00:00 2001 From: Mathias Fredriksson Date: Wed, 20 Mar 2024 16:12:47 +0000 Subject: [PATCH 19/19] update join comment --- coderd/database/queries.sql.go | 4 +++- coderd/database/queries/insights.sql | 4 +++- 2 files changed, 6 insertions(+), 2 deletions(-) diff --git a/coderd/database/queries.sql.go b/coderd/database/queries.sql.go index b1dd8eb75d795a..d89b349fcccd4c 100644 --- a/coderd/database/queries.sql.go +++ b/coderd/database/queries.sql.go @@ -1849,7 +1849,9 @@ SELECT 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. + -- The joins in this query are necessary to associate an app with a + -- template, we use this to get the app metadata like display name + -- and icon. SELECT app.display_name, app.slug diff --git a/coderd/database/queries/insights.sql b/coderd/database/queries/insights.sql index 0877523898a1e1..81e721d1700cb9 100644 --- a/coderd/database/queries/insights.sql +++ b/coderd/database/queries/insights.sql @@ -282,7 +282,9 @@ SELECT 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. + -- The joins in this query are necessary to associate an app with a + -- template, we use this to get the app metadata like display name + -- and icon. SELECT app.display_name, app.slug