From cd9be678b24761248f1d1d8231fc2de67a5c9e37 Mon Sep 17 00:00:00 2001 From: Thomas Krampl Date: Wed, 6 Mar 2024 16:50:35 +0100 Subject: [PATCH 1/2] Initial work on materialized views --- internal/database/cost.go | 12 +- internal/database/gensql/cost.sql.go | 186 ++++++++++-------- internal/database/gensql/mock_querier.go | 42 ++-- internal/database/gensql/models.go | 24 +++ internal/database/gensql/querier.go | 66 ++++++- internal/database/gensql/resourceusage.sql.go | 37 ++-- .../migrations/0004_cost_mat_views.sql | 73 +++++++ .../migrations/0005_resource_mat_views.sql | 46 +++++ internal/database/mock_database.go | 42 ++-- internal/database/queries/cost.sql | 61 ++---- internal/database/queries/resourceusage.sql | 37 ++-- internal/graph/cost.go | 2 +- 12 files changed, 397 insertions(+), 231 deletions(-) create mode 100644 internal/database/migrations/0004_cost_mat_views.sql create mode 100644 internal/database/migrations/0005_resource_mat_views.sql diff --git a/internal/database/cost.go b/internal/database/cost.go index bbfb5ce4e..ebfaec112 100644 --- a/internal/database/cost.go +++ b/internal/database/cost.go @@ -12,10 +12,10 @@ type CostRepo interface { CostUpsert(ctx context.Context, arg []gensql.CostUpsertParams) *gensql.CostUpsertBatchResults DailyCostForApp(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, environment string, teamSlug slug.Slug, app string) ([]*gensql.Cost, error) DailyCostForTeam(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, teamSlug slug.Slug) ([]*gensql.Cost, error) - DailyEnvCostForTeam(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, environment *string, teamSlug slug.Slug) ([]*gensql.DailyEnvCostForTeamRow, error) + DailyEnvCostForTeam(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, environment *string, teamSlug slug.Slug) ([]*gensql.CostDailyTeam, error) LastCostDate(ctx context.Context) (pgtype.Date, error) - MonthlyCostForApp(ctx context.Context, teamSlug slug.Slug, app string, environment string) ([]*gensql.MonthlyCostForAppRow, error) - MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*gensql.MonthlyCostForTeamRow, error) + MonthlyCostForApp(ctx context.Context, teamSlug slug.Slug, app string, environment string) ([]*gensql.CostMonthlyApp, error) + MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*gensql.CostMonthlyTeam, error) } var _ CostRepo = (*database)(nil) @@ -42,7 +42,7 @@ func (d *database) DailyCostForTeam(ctx context.Context, fromDate pgtype.Date, t }) } -func (d *database) DailyEnvCostForTeam(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, environment *string, teamSlug slug.Slug) ([]*gensql.DailyEnvCostForTeamRow, error) { +func (d *database) DailyEnvCostForTeam(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, environment *string, teamSlug slug.Slug) ([]*gensql.CostDailyTeam, error) { return d.querier.DailyEnvCostForTeam(ctx, gensql.DailyEnvCostForTeamParams{ FromDate: fromDate, ToDate: toDate, @@ -55,7 +55,7 @@ func (d *database) LastCostDate(ctx context.Context) (pgtype.Date, error) { return d.querier.LastCostDate(ctx) } -func (d *database) MonthlyCostForApp(ctx context.Context, teamSlug slug.Slug, app string, environment string) ([]*gensql.MonthlyCostForAppRow, error) { +func (d *database) MonthlyCostForApp(ctx context.Context, teamSlug slug.Slug, app string, environment string) ([]*gensql.CostMonthlyApp, error) { return d.querier.MonthlyCostForApp(ctx, gensql.MonthlyCostForAppParams{ TeamSlug: teamSlug, App: app, @@ -63,6 +63,6 @@ func (d *database) MonthlyCostForApp(ctx context.Context, teamSlug slug.Slug, ap }) } -func (d *database) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*gensql.MonthlyCostForTeamRow, error) { +func (d *database) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*gensql.CostMonthlyTeam, error) { return d.querier.MonthlyCostForTeam(ctx, teamSlug) } diff --git a/internal/database/gensql/cost.sql.go b/internal/database/gensql/cost.sql.go index 6955cd97b..4155ff65e 100644 --- a/internal/database/gensql/cost.sql.go +++ b/internal/database/gensql/cost.sql.go @@ -118,20 +118,13 @@ func (q *Queries) DailyCostForTeam(ctx context.Context, arg DailyCostForTeamPara } const dailyEnvCostForTeam = `-- name: DailyEnvCostForTeam :many -SELECT - team_slug, - app, - date, - SUM(daily_cost)::real AS daily_cost -FROM - cost +SELECT team_slug, app, environment, date, daily_cost +FROM cost_daily_team WHERE date >= $1::date AND date <= $2::date - AND environment = $3 - AND team_slug = $4::slug -GROUP BY - team_slug, app, date + AND team_slug = $3::slug + AND environment = $4 ORDER BY date, app ASC ` @@ -139,35 +132,54 @@ ORDER BY type DailyEnvCostForTeamParams struct { FromDate pgtype.Date ToDate pgtype.Date - Environment *string TeamSlug slug.Slug -} - -type DailyEnvCostForTeamRow struct { - TeamSlug slug.Slug - App string - Date pgtype.Date - DailyCost float32 + Environment *string } // DailyEnvCostForTeam will fetch the daily cost for a specific team and environment across all apps in a date range. -func (q *Queries) DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*DailyEnvCostForTeamRow, error) { +// SELECT +// +// team_slug, +// app, +// date, +// SUM(daily_cost)::real AS daily_cost +// +// FROM +// +// cost +// +// WHERE +// +// date >= @from_date::date +// AND date <= @to_date::date +// AND environment = @environment +// AND team_slug = @team_slug::slug +// +// GROUP BY +// +// team_slug, app, date +// +// ORDER BY +// +// date, app ASC; +func (q *Queries) DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*CostDailyTeam, error) { rows, err := q.db.Query(ctx, dailyEnvCostForTeam, arg.FromDate, arg.ToDate, - arg.Environment, arg.TeamSlug, + arg.Environment, ) if err != nil { return nil, err } defer rows.Close() - items := []*DailyEnvCostForTeamRow{} + items := []*CostDailyTeam{} for rows.Next() { - var i DailyEnvCostForTeamRow + var i CostDailyTeam if err := rows.Scan( &i.TeamSlug, &i.App, + &i.Environment, &i.Date, &i.DailyCost, ); err != nil { @@ -197,28 +209,11 @@ func (q *Queries) LastCostDate(ctx context.Context) (pgtype.Date, error) { } const monthlyCostForApp = `-- name: MonthlyCostForApp :many -WITH last_run AS ( - SELECT MAX(date)::date AS "last_run" - FROM cost -) -SELECT - team_slug, - app, - environment, - date_trunc('month', date)::date AS month, - -- Extract last day of known cost samples for the month, or the last recorded date - -- This helps with estimation etc - MAX(CASE - WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' - ELSE date_trunc('day', last_run) - END)::date AS last_recorded_date, - SUM(daily_cost)::real AS daily_cost -FROM cost c -LEFT JOIN last_run ON true -WHERE c.team_slug = $1::slug -AND c.app = $2 -AND c.environment = $3::text -GROUP BY team_slug, app, environment, month +SELECT team_slug, app, environment, month, last_recorded_date, daily_cost +FROM cost_monthly_app +WHERE team_slug = $1::slug +AND app = $2 +AND environment = $3::text ORDER BY month DESC LIMIT 12 ` @@ -229,24 +224,43 @@ type MonthlyCostForAppParams struct { Environment string } -type MonthlyCostForAppRow struct { - TeamSlug slug.Slug - App string - Environment *string - Month pgtype.Date - LastRecordedDate pgtype.Date - DailyCost float32 -} - -func (q *Queries) MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*MonthlyCostForAppRow, error) { +// WITH last_run AS ( +// +// SELECT MAX(date)::date AS "last_run" +// FROM cost +// +// ) +// SELECT +// +// team_slug, +// app, +// environment, +// date_trunc('month', date)::date AS month, +// -- Extract last day of known cost samples for the month, or the last recorded date +// -- This helps with estimation etc +// MAX(CASE +// WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' +// ELSE date_trunc('day', last_run) +// END)::date AS last_recorded_date, +// SUM(daily_cost)::real AS daily_cost +// +// FROM cost c +// LEFT JOIN last_run ON true +// WHERE c.team_slug = @team_slug::slug +// AND c.app = @app +// AND c.environment = @environment::text +// GROUP BY team_slug, app, environment, month +// ORDER BY month DESC +// LIMIT 12; +func (q *Queries) MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*CostMonthlyApp, error) { rows, err := q.db.Query(ctx, monthlyCostForApp, arg.TeamSlug, arg.App, arg.Environment) if err != nil { return nil, err } defer rows.Close() - items := []*MonthlyCostForAppRow{} + items := []*CostMonthlyApp{} for rows.Next() { - var i MonthlyCostForAppRow + var i CostMonthlyApp if err := rows.Scan( &i.TeamSlug, &i.App, @@ -266,44 +280,46 @@ func (q *Queries) MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppPa } const monthlyCostForTeam = `-- name: MonthlyCostForTeam :many -WITH last_run AS ( - SELECT MAX(date)::date AS "last_run" - FROM cost -) -SELECT - team_slug, - date_trunc('month', date)::date AS month, - -- Extract last day of known cost samples for the month, or the last recorded date - -- This helps with estimation etc - MAX(CASE - WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' - ELSE date_trunc('day', last_run) - END)::date AS last_recorded_date, - SUM(daily_cost)::real AS daily_cost -FROM cost c -LEFT JOIN last_run ON true -WHERE c.team_slug = $1::slug -GROUP BY team_slug, month +SELECT team_slug, month, last_recorded_date, daily_cost +FROM cost_monthly_team +WHERE team_slug = $1::slug ORDER BY month DESC LIMIT 12 ` -type MonthlyCostForTeamRow struct { - TeamSlug slug.Slug - Month pgtype.Date - LastRecordedDate pgtype.Date - DailyCost float32 -} - -func (q *Queries) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*MonthlyCostForTeamRow, error) { +// WITH last_run AS ( +// +// SELECT MAX(date)::date AS "last_run" +// FROM cost +// +// ) +// SELECT +// +// team_slug, +// date_trunc('month', date)::date AS month, +// -- Extract last day of known cost samples for the month, or the last recorded date +// -- This helps with estimation etc +// MAX(CASE +// WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' +// ELSE date_trunc('day', last_run) +// END)::date AS last_recorded_date, +// SUM(daily_cost)::real AS daily_cost +// +// FROM cost c +// LEFT JOIN last_run ON true +// WHERE c.team_slug = @team_slug::slug +// GROUP BY team_slug, month +// ORDER BY month DESC +// LIMIT 12; +func (q *Queries) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*CostMonthlyTeam, error) { rows, err := q.db.Query(ctx, monthlyCostForTeam, teamSlug) if err != nil { return nil, err } defer rows.Close() - items := []*MonthlyCostForTeamRow{} + items := []*CostMonthlyTeam{} for rows.Next() { - var i MonthlyCostForTeamRow + var i CostMonthlyTeam if err := rows.Scan( &i.TeamSlug, &i.Month, diff --git a/internal/database/gensql/mock_querier.go b/internal/database/gensql/mock_querier.go index a21fc4d96..896f799c6 100644 --- a/internal/database/gensql/mock_querier.go +++ b/internal/database/gensql/mock_querier.go @@ -1112,23 +1112,23 @@ func (_c *MockQuerier_DailyCostForTeam_Call) RunAndReturn(run func(context.Conte } // DailyEnvCostForTeam provides a mock function with given fields: ctx, arg -func (_m *MockQuerier) DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*DailyEnvCostForTeamRow, error) { +func (_m *MockQuerier) DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*CostDailyTeam, error) { ret := _m.Called(ctx, arg) if len(ret) == 0 { panic("no return value specified for DailyEnvCostForTeam") } - var r0 []*DailyEnvCostForTeamRow + var r0 []*CostDailyTeam var r1 error - if rf, ok := ret.Get(0).(func(context.Context, DailyEnvCostForTeamParams) ([]*DailyEnvCostForTeamRow, error)); ok { + if rf, ok := ret.Get(0).(func(context.Context, DailyEnvCostForTeamParams) ([]*CostDailyTeam, error)); ok { return rf(ctx, arg) } - if rf, ok := ret.Get(0).(func(context.Context, DailyEnvCostForTeamParams) []*DailyEnvCostForTeamRow); ok { + if rf, ok := ret.Get(0).(func(context.Context, DailyEnvCostForTeamParams) []*CostDailyTeam); ok { r0 = rf(ctx, arg) } else { if ret.Get(0) != nil { - r0 = ret.Get(0).([]*DailyEnvCostForTeamRow) + r0 = ret.Get(0).([]*CostDailyTeam) } } @@ -1160,12 +1160,12 @@ func (_c *MockQuerier_DailyEnvCostForTeam_Call) Run(run func(ctx context.Context return _c } -func (_c *MockQuerier_DailyEnvCostForTeam_Call) Return(_a0 []*DailyEnvCostForTeamRow, _a1 error) *MockQuerier_DailyEnvCostForTeam_Call { +func (_c *MockQuerier_DailyEnvCostForTeam_Call) Return(_a0 []*CostDailyTeam, _a1 error) *MockQuerier_DailyEnvCostForTeam_Call { _c.Call.Return(_a0, _a1) return _c } -func (_c *MockQuerier_DailyEnvCostForTeam_Call) RunAndReturn(run func(context.Context, DailyEnvCostForTeamParams) ([]*DailyEnvCostForTeamRow, error)) *MockQuerier_DailyEnvCostForTeam_Call { +func (_c *MockQuerier_DailyEnvCostForTeam_Call) RunAndReturn(run func(context.Context, DailyEnvCostForTeamParams) ([]*CostDailyTeam, error)) *MockQuerier_DailyEnvCostForTeam_Call { _c.Call.Return(run) return _c } @@ -4936,23 +4936,23 @@ func (_c *MockQuerier_MaxResourceUtilizationDate_Call) RunAndReturn(run func(con } // MonthlyCostForApp provides a mock function with given fields: ctx, arg -func (_m *MockQuerier) MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*MonthlyCostForAppRow, error) { +func (_m *MockQuerier) MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*CostMonthlyApp, error) { ret := _m.Called(ctx, arg) if len(ret) == 0 { panic("no return value specified for MonthlyCostForApp") } - var r0 []*MonthlyCostForAppRow + var r0 []*CostMonthlyApp var r1 error - if rf, ok := ret.Get(0).(func(context.Context, MonthlyCostForAppParams) ([]*MonthlyCostForAppRow, error)); ok { + if rf, ok := ret.Get(0).(func(context.Context, MonthlyCostForAppParams) ([]*CostMonthlyApp, error)); ok { return rf(ctx, arg) } - if rf, ok := ret.Get(0).(func(context.Context, MonthlyCostForAppParams) []*MonthlyCostForAppRow); ok { + if rf, ok := ret.Get(0).(func(context.Context, MonthlyCostForAppParams) []*CostMonthlyApp); ok { r0 = rf(ctx, arg) } else { if ret.Get(0) != nil { - r0 = ret.Get(0).([]*MonthlyCostForAppRow) + r0 = ret.Get(0).([]*CostMonthlyApp) } } @@ -4984,34 +4984,34 @@ func (_c *MockQuerier_MonthlyCostForApp_Call) Run(run func(ctx context.Context, return _c } -func (_c *MockQuerier_MonthlyCostForApp_Call) Return(_a0 []*MonthlyCostForAppRow, _a1 error) *MockQuerier_MonthlyCostForApp_Call { +func (_c *MockQuerier_MonthlyCostForApp_Call) Return(_a0 []*CostMonthlyApp, _a1 error) *MockQuerier_MonthlyCostForApp_Call { _c.Call.Return(_a0, _a1) return _c } -func (_c *MockQuerier_MonthlyCostForApp_Call) RunAndReturn(run func(context.Context, MonthlyCostForAppParams) ([]*MonthlyCostForAppRow, error)) *MockQuerier_MonthlyCostForApp_Call { +func (_c *MockQuerier_MonthlyCostForApp_Call) RunAndReturn(run func(context.Context, MonthlyCostForAppParams) ([]*CostMonthlyApp, error)) *MockQuerier_MonthlyCostForApp_Call { _c.Call.Return(run) return _c } // MonthlyCostForTeam provides a mock function with given fields: ctx, teamSlug -func (_m *MockQuerier) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*MonthlyCostForTeamRow, error) { +func (_m *MockQuerier) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*CostMonthlyTeam, error) { ret := _m.Called(ctx, teamSlug) if len(ret) == 0 { panic("no return value specified for MonthlyCostForTeam") } - var r0 []*MonthlyCostForTeamRow + var r0 []*CostMonthlyTeam var r1 error - if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) ([]*MonthlyCostForTeamRow, error)); ok { + if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) ([]*CostMonthlyTeam, error)); ok { return rf(ctx, teamSlug) } - if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) []*MonthlyCostForTeamRow); ok { + if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) []*CostMonthlyTeam); ok { r0 = rf(ctx, teamSlug) } else { if ret.Get(0) != nil { - r0 = ret.Get(0).([]*MonthlyCostForTeamRow) + r0 = ret.Get(0).([]*CostMonthlyTeam) } } @@ -5043,12 +5043,12 @@ func (_c *MockQuerier_MonthlyCostForTeam_Call) Run(run func(ctx context.Context, return _c } -func (_c *MockQuerier_MonthlyCostForTeam_Call) Return(_a0 []*MonthlyCostForTeamRow, _a1 error) *MockQuerier_MonthlyCostForTeam_Call { +func (_c *MockQuerier_MonthlyCostForTeam_Call) Return(_a0 []*CostMonthlyTeam, _a1 error) *MockQuerier_MonthlyCostForTeam_Call { _c.Call.Return(_a0, _a1) return _c } -func (_c *MockQuerier_MonthlyCostForTeam_Call) RunAndReturn(run func(context.Context, slug.Slug) ([]*MonthlyCostForTeamRow, error)) *MockQuerier_MonthlyCostForTeam_Call { +func (_c *MockQuerier_MonthlyCostForTeam_Call) RunAndReturn(run func(context.Context, slug.Slug) ([]*CostMonthlyTeam, error)) *MockQuerier_MonthlyCostForTeam_Call { _c.Call.Return(run) return _c } diff --git a/internal/database/gensql/models.go b/internal/database/gensql/models.go index 79341c1bd..150919a65 100644 --- a/internal/database/gensql/models.go +++ b/internal/database/gensql/models.go @@ -230,6 +230,30 @@ type Cost struct { DailyCost float32 } +type CostDailyTeam struct { + TeamSlug slug.Slug + App string + Environment *string + Date pgtype.Date + DailyCost float32 +} + +type CostMonthlyApp struct { + TeamSlug slug.Slug + App string + Environment *string + Month pgtype.Date + LastRecordedDate pgtype.Date + DailyCost float32 +} + +type CostMonthlyTeam struct { + TeamSlug slug.Slug + Month pgtype.Date + LastRecordedDate pgtype.Date + DailyCost float32 +} + type Reconciler struct { Name string DisplayName string diff --git a/internal/database/gensql/querier.go b/internal/database/gensql/querier.go index 8a606fbc0..90d774b4d 100644 --- a/internal/database/gensql/querier.go +++ b/internal/database/gensql/querier.go @@ -39,7 +39,23 @@ type Querier interface { // DailyCostForTeam will fetch the daily cost for a specific team across all apps and envs in a date range. DailyCostForTeam(ctx context.Context, arg DailyCostForTeamParams) ([]*Cost, error) // DailyEnvCostForTeam will fetch the daily cost for a specific team and environment across all apps in a date range. - DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*DailyEnvCostForTeamRow, error) + // SELECT + // team_slug, + // app, + // date, + // SUM(daily_cost)::real AS daily_cost + // FROM + // cost + // WHERE + // date >= @from_date::date + // AND date <= @to_date::date + // AND environment = @environment + // AND team_slug = @team_slug::slug + // GROUP BY + // team_slug, app, date + // ORDER BY + // date, app ASC; + DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*CostDailyTeam, error) // DailyVulnerabilityForTeam will return the metrics for the given team from first to last date. DailyVulnerabilityForTeam(ctx context.Context, arg DailyVulnerabilityForTeamParams) ([]*DailyVulnerabilityForTeamRow, error) // DailyVulnerabilityForTeamAndEnvironment will return the metrics for the given team and environment from first to last date. @@ -111,8 +127,52 @@ type Querier interface { ListRepositoriesByAuthorization(ctx context.Context, arg ListRepositoriesByAuthorizationParams) ([]string, error) // MaxResourceUtilizationDate will return the max date for resource utilization records. MaxResourceUtilizationDate(ctx context.Context) (pgtype.Timestamptz, error) - MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*MonthlyCostForAppRow, error) - MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*MonthlyCostForTeamRow, error) + // WITH last_run AS ( + // SELECT MAX(date)::date AS "last_run" + // FROM cost + // ) + // SELECT + // team_slug, + // app, + // environment, + // date_trunc('month', date)::date AS month, + // -- Extract last day of known cost samples for the month, or the last recorded date + // -- This helps with estimation etc + // MAX(CASE + // WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' + // ELSE date_trunc('day', last_run) + // END)::date AS last_recorded_date, + // SUM(daily_cost)::real AS daily_cost + // FROM cost c + // LEFT JOIN last_run ON true + // WHERE c.team_slug = @team_slug::slug + // AND c.app = @app + // AND c.environment = @environment::text + // GROUP BY team_slug, app, environment, month + // ORDER BY month DESC + // LIMIT 12; + MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*CostMonthlyApp, error) + // WITH last_run AS ( + // SELECT MAX(date)::date AS "last_run" + // FROM cost + // ) + // SELECT + // team_slug, + // date_trunc('month', date)::date AS month, + // -- Extract last day of known cost samples for the month, or the last recorded date + // -- This helps with estimation etc + // MAX(CASE + // WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' + // ELSE date_trunc('day', last_run) + // END)::date AS last_recorded_date, + // SUM(daily_cost)::real AS daily_cost + // FROM cost c + // LEFT JOIN last_run ON true + // WHERE c.team_slug = @team_slug::slug + // GROUP BY team_slug, month + // ORDER BY month DESC + // LIMIT 12; + MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*CostMonthlyTeam, error) RemoveAllServiceAccountRoles(ctx context.Context, serviceAccountID uuid.UUID) error RemoveApiKeysFromServiceAccount(ctx context.Context, serviceAccountID uuid.UUID) error RemoveReconcilerOptOut(ctx context.Context, arg RemoveReconcilerOptOutParams) error diff --git a/internal/database/gensql/resourceusage.sql.go b/internal/database/gensql/resourceusage.sql.go index ecb6b791c..403f43782 100644 --- a/internal/database/gensql/resourceusage.sql.go +++ b/internal/database/gensql/resourceusage.sql.go @@ -12,10 +12,10 @@ import ( const averageResourceUtilizationForTeam = `-- name: AverageResourceUtilizationForTeam :one SELECT - (SUM(usage) / 24 / 7)::double precision AS usage, - (SUM(request) / 24 / 7)::double precision AS request + (SUM(usage)::double precision / 24 / 7)::double precision AS usage, + (SUM(request)::double precision / 24 / 7)::double precision AS request FROM - resource_utilization_metrics + resource_utilization_team WHERE team_slug = $1 AND resource_type = $2 @@ -119,19 +119,17 @@ func (q *Queries) ResourceUtilizationForApp(ctx context.Context, arg ResourceUti const resourceUtilizationForTeam = `-- name: ResourceUtilizationForTeam :many SELECT - SUM(usage)::double precision AS usage, - SUM(request)::double precision AS request, + usage, + request, timestamp FROM - resource_utilization_metrics + resource_utilization_team WHERE environment = $1 AND team_slug = $2 AND resource_type = $3 AND timestamp >= $4::timestamptz AND timestamp < $5::timestamptz -GROUP BY - timestamp ORDER BY timestamp ASC ` @@ -239,10 +237,10 @@ func (q *Queries) ResourceUtilizationOverageForTeam(ctx context.Context, arg Res const resourceUtilizationRangeForApp = `-- name: ResourceUtilizationRangeForApp :one SELECT - MIN(timestamp)::timestamptz AS "from", - MAX(timestamp)::timestamptz AS "to" + "from", + "to" FROM - resource_utilization_metrics + resource_app_range WHERE environment = $1 AND team_slug = $2 @@ -269,18 +267,13 @@ func (q *Queries) ResourceUtilizationRangeForApp(ctx context.Context, arg Resour } const resourceUtilizationRangeForTeam = `-- name: ResourceUtilizationRangeForTeam :one -WITH team_range AS ( - SELECT timestamp - FROM - resource_utilization_metrics - WHERE - team_slug = $1 -) SELECT - MIN(timestamp)::timestamptz AS "from", - MAX(timestamp)::timestamptz AS "to" + "from", + "to" FROM - team_range + resource_team_range +WHERE + team_slug = $1 ` type ResourceUtilizationRangeForTeamRow struct { @@ -345,7 +338,7 @@ SELECT SUM(request)::double precision AS request, timestamp FROM - resource_utilization_metrics + resource_utilization_team WHERE team_slug = $1 AND resource_type = $2 diff --git a/internal/database/migrations/0004_cost_mat_views.sql b/internal/database/migrations/0004_cost_mat_views.sql new file mode 100644 index 000000000..e3c3bb58a --- /dev/null +++ b/internal/database/migrations/0004_cost_mat_views.sql @@ -0,0 +1,73 @@ +-- +goose Up + +-- Monthly per team + +DROP MATERIALIZED VIEW IF EXISTS cost_monthly_team; +CREATE MATERIALIZED VIEW cost_monthly_team AS +WITH last_run AS ( + SELECT MAX(date)::date AS "last_run" + FROM cost +) +SELECT + team_slug, + date_trunc('month', date)::date AS month, + -- Extract last day of known cost samples for the month, or the last recorded date + -- This helps with estimation etc + MAX(CASE + WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' + ELSE date_trunc('day', last_run) + END)::date AS last_recorded_date, + SUM(daily_cost)::real AS daily_cost +FROM cost c +LEFT JOIN last_run ON true +GROUP BY team_slug, month +ORDER BY month DESC +; + +CREATE INDEX ON cost_monthly_team (team_slug, month); + +-- Monthly per app + +DROP MATERIALIZED VIEW IF EXISTS cost_monthly_app; +CREATE MATERIALIZED VIEW cost_monthly_app AS +WITH last_run AS ( + SELECT MAX(date)::date AS "last_run" + FROM cost +) +SELECT + team_slug, + app, + environment, + date_trunc('month', date)::date AS month, + -- Extract last day of known cost samples for the month, or the last recorded date + -- This helps with estimation etc + MAX(CASE + WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' + ELSE date_trunc('day', last_run) + END)::date AS last_recorded_date, + SUM(daily_cost)::real AS daily_cost +FROM cost c +LEFT JOIN last_run ON true +GROUP BY team_slug, app, environment, month +ORDER BY month DESC +; + +CREATE INDEX ON cost_monthly_app (team_slug, app, environment, month); + +-- Daily per team + +DROP MATERIALIZED VIEW IF EXISTS cost_daily_team; +CREATE MATERIALIZED VIEW cost_daily_team AS +SELECT + team_slug, + app, + environment, + date, + SUM(daily_cost)::real AS daily_cost +FROM + cost +GROUP BY + team_slug, app, date, environment +; + +CREATE INDEX ON cost_daily_team (team_slug, app, environment, date); diff --git a/internal/database/migrations/0005_resource_mat_views.sql b/internal/database/migrations/0005_resource_mat_views.sql new file mode 100644 index 000000000..6860b0b05 --- /dev/null +++ b/internal/database/migrations/0005_resource_mat_views.sql @@ -0,0 +1,46 @@ +-- +goose Up + +-- Team range for resource utilization +CREATE MATERIALIZED VIEW resource_team_range AS +SELECT + team_slug, + MIN(timestamp)::timestamptz AS "from", + MAX(timestamp)::timestamptz AS "to" +FROM + resource_utilization_metrics +GROUP BY + team_slug; + +CREATE INDEX ON resource_team_range (team_slug); + +-- App range for resource utilization +CREATE MATERIALIZED VIEW resource_app_range AS +SELECT + team_slug, + app, + environment, + MIN(timestamp)::timestamptz AS "from", + MAX(timestamp)::timestamptz AS "to" +FROM + resource_utilization_metrics +GROUP BY + team_slug, app, environment; + +CREATE INDEX ON resource_app_range (team_slug, app, environment); + +-- Resource utilization for team + +CREATE MATERIALIZED VIEW resource_utilization_team AS +SELECT + team_slug, + environment, + resource_type, + timestamp, + SUM(usage)::double precision AS usage, + SUM(request)::double precision AS request +FROM + resource_utilization_metrics +GROUP BY + team_slug, environment, resource_type, timestamp; + +CREATE INDEX ON resource_utilization_team (team_slug, environment, resource_type, timestamp); diff --git a/internal/database/mock_database.go b/internal/database/mock_database.go index 181247658..0feea8af7 100644 --- a/internal/database/mock_database.go +++ b/internal/database/mock_database.go @@ -1103,23 +1103,23 @@ func (_c *MockDatabase_DailyCostForTeam_Call) RunAndReturn(run func(context.Cont } // DailyEnvCostForTeam provides a mock function with given fields: ctx, fromDate, toDate, environment, teamSlug -func (_m *MockDatabase) DailyEnvCostForTeam(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, environment *string, teamSlug slug.Slug) ([]*gensql.DailyEnvCostForTeamRow, error) { +func (_m *MockDatabase) DailyEnvCostForTeam(ctx context.Context, fromDate pgtype.Date, toDate pgtype.Date, environment *string, teamSlug slug.Slug) ([]*gensql.CostDailyTeam, error) { ret := _m.Called(ctx, fromDate, toDate, environment, teamSlug) if len(ret) == 0 { panic("no return value specified for DailyEnvCostForTeam") } - var r0 []*gensql.DailyEnvCostForTeamRow + var r0 []*gensql.CostDailyTeam var r1 error - if rf, ok := ret.Get(0).(func(context.Context, pgtype.Date, pgtype.Date, *string, slug.Slug) ([]*gensql.DailyEnvCostForTeamRow, error)); ok { + if rf, ok := ret.Get(0).(func(context.Context, pgtype.Date, pgtype.Date, *string, slug.Slug) ([]*gensql.CostDailyTeam, error)); ok { return rf(ctx, fromDate, toDate, environment, teamSlug) } - if rf, ok := ret.Get(0).(func(context.Context, pgtype.Date, pgtype.Date, *string, slug.Slug) []*gensql.DailyEnvCostForTeamRow); ok { + if rf, ok := ret.Get(0).(func(context.Context, pgtype.Date, pgtype.Date, *string, slug.Slug) []*gensql.CostDailyTeam); ok { r0 = rf(ctx, fromDate, toDate, environment, teamSlug) } else { if ret.Get(0) != nil { - r0 = ret.Get(0).([]*gensql.DailyEnvCostForTeamRow) + r0 = ret.Get(0).([]*gensql.CostDailyTeam) } } @@ -1154,12 +1154,12 @@ func (_c *MockDatabase_DailyEnvCostForTeam_Call) Run(run func(ctx context.Contex return _c } -func (_c *MockDatabase_DailyEnvCostForTeam_Call) Return(_a0 []*gensql.DailyEnvCostForTeamRow, _a1 error) *MockDatabase_DailyEnvCostForTeam_Call { +func (_c *MockDatabase_DailyEnvCostForTeam_Call) Return(_a0 []*gensql.CostDailyTeam, _a1 error) *MockDatabase_DailyEnvCostForTeam_Call { _c.Call.Return(_a0, _a1) return _c } -func (_c *MockDatabase_DailyEnvCostForTeam_Call) RunAndReturn(run func(context.Context, pgtype.Date, pgtype.Date, *string, slug.Slug) ([]*gensql.DailyEnvCostForTeamRow, error)) *MockDatabase_DailyEnvCostForTeam_Call { +func (_c *MockDatabase_DailyEnvCostForTeam_Call) RunAndReturn(run func(context.Context, pgtype.Date, pgtype.Date, *string, slug.Slug) ([]*gensql.CostDailyTeam, error)) *MockDatabase_DailyEnvCostForTeam_Call { _c.Call.Return(run) return _c } @@ -4569,23 +4569,23 @@ func (_c *MockDatabase_MaxResourceUtilizationDate_Call) RunAndReturn(run func(co } // MonthlyCostForApp provides a mock function with given fields: ctx, teamSlug, app, environment -func (_m *MockDatabase) MonthlyCostForApp(ctx context.Context, teamSlug slug.Slug, app string, environment string) ([]*gensql.MonthlyCostForAppRow, error) { +func (_m *MockDatabase) MonthlyCostForApp(ctx context.Context, teamSlug slug.Slug, app string, environment string) ([]*gensql.CostMonthlyApp, error) { ret := _m.Called(ctx, teamSlug, app, environment) if len(ret) == 0 { panic("no return value specified for MonthlyCostForApp") } - var r0 []*gensql.MonthlyCostForAppRow + var r0 []*gensql.CostMonthlyApp var r1 error - if rf, ok := ret.Get(0).(func(context.Context, slug.Slug, string, string) ([]*gensql.MonthlyCostForAppRow, error)); ok { + if rf, ok := ret.Get(0).(func(context.Context, slug.Slug, string, string) ([]*gensql.CostMonthlyApp, error)); ok { return rf(ctx, teamSlug, app, environment) } - if rf, ok := ret.Get(0).(func(context.Context, slug.Slug, string, string) []*gensql.MonthlyCostForAppRow); ok { + if rf, ok := ret.Get(0).(func(context.Context, slug.Slug, string, string) []*gensql.CostMonthlyApp); ok { r0 = rf(ctx, teamSlug, app, environment) } else { if ret.Get(0) != nil { - r0 = ret.Get(0).([]*gensql.MonthlyCostForAppRow) + r0 = ret.Get(0).([]*gensql.CostMonthlyApp) } } @@ -4619,34 +4619,34 @@ func (_c *MockDatabase_MonthlyCostForApp_Call) Run(run func(ctx context.Context, return _c } -func (_c *MockDatabase_MonthlyCostForApp_Call) Return(_a0 []*gensql.MonthlyCostForAppRow, _a1 error) *MockDatabase_MonthlyCostForApp_Call { +func (_c *MockDatabase_MonthlyCostForApp_Call) Return(_a0 []*gensql.CostMonthlyApp, _a1 error) *MockDatabase_MonthlyCostForApp_Call { _c.Call.Return(_a0, _a1) return _c } -func (_c *MockDatabase_MonthlyCostForApp_Call) RunAndReturn(run func(context.Context, slug.Slug, string, string) ([]*gensql.MonthlyCostForAppRow, error)) *MockDatabase_MonthlyCostForApp_Call { +func (_c *MockDatabase_MonthlyCostForApp_Call) RunAndReturn(run func(context.Context, slug.Slug, string, string) ([]*gensql.CostMonthlyApp, error)) *MockDatabase_MonthlyCostForApp_Call { _c.Call.Return(run) return _c } // MonthlyCostForTeam provides a mock function with given fields: ctx, teamSlug -func (_m *MockDatabase) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*gensql.MonthlyCostForTeamRow, error) { +func (_m *MockDatabase) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*gensql.CostMonthlyTeam, error) { ret := _m.Called(ctx, teamSlug) if len(ret) == 0 { panic("no return value specified for MonthlyCostForTeam") } - var r0 []*gensql.MonthlyCostForTeamRow + var r0 []*gensql.CostMonthlyTeam var r1 error - if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) ([]*gensql.MonthlyCostForTeamRow, error)); ok { + if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) ([]*gensql.CostMonthlyTeam, error)); ok { return rf(ctx, teamSlug) } - if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) []*gensql.MonthlyCostForTeamRow); ok { + if rf, ok := ret.Get(0).(func(context.Context, slug.Slug) []*gensql.CostMonthlyTeam); ok { r0 = rf(ctx, teamSlug) } else { if ret.Get(0) != nil { - r0 = ret.Get(0).([]*gensql.MonthlyCostForTeamRow) + r0 = ret.Get(0).([]*gensql.CostMonthlyTeam) } } @@ -4678,12 +4678,12 @@ func (_c *MockDatabase_MonthlyCostForTeam_Call) Run(run func(ctx context.Context return _c } -func (_c *MockDatabase_MonthlyCostForTeam_Call) Return(_a0 []*gensql.MonthlyCostForTeamRow, _a1 error) *MockDatabase_MonthlyCostForTeam_Call { +func (_c *MockDatabase_MonthlyCostForTeam_Call) Return(_a0 []*gensql.CostMonthlyTeam, _a1 error) *MockDatabase_MonthlyCostForTeam_Call { _c.Call.Return(_a0, _a1) return _c } -func (_c *MockDatabase_MonthlyCostForTeam_Call) RunAndReturn(run func(context.Context, slug.Slug) ([]*gensql.MonthlyCostForTeamRow, error)) *MockDatabase_MonthlyCostForTeam_Call { +func (_c *MockDatabase_MonthlyCostForTeam_Call) RunAndReturn(run func(context.Context, slug.Slug) ([]*gensql.CostMonthlyTeam, error)) *MockDatabase_MonthlyCostForTeam_Call { _c.Call.Return(run) return _c } diff --git a/internal/database/queries/cost.sql b/internal/database/queries/cost.sql index e3eb1d3c9..1d02cb1b7 100644 --- a/internal/database/queries/cost.sql +++ b/internal/database/queries/cost.sql @@ -6,50 +6,18 @@ FROM cost; -- name: MonthlyCostForApp :many -WITH last_run AS ( - SELECT MAX(date)::date AS "last_run" - FROM cost -) -SELECT - team_slug, - app, - environment, - date_trunc('month', date)::date AS month, - -- Extract last day of known cost samples for the month, or the last recorded date - -- This helps with estimation etc - MAX(CASE - WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' - ELSE date_trunc('day', last_run) - END)::date AS last_recorded_date, - SUM(daily_cost)::real AS daily_cost -FROM cost c -LEFT JOIN last_run ON true -WHERE c.team_slug = @team_slug::slug -AND c.app = @app -AND c.environment = @environment::text -GROUP BY team_slug, app, environment, month +SELECT * +FROM cost_monthly_app +WHERE team_slug = @team_slug::slug +AND app = @app +AND environment = @environment::text ORDER BY month DESC LIMIT 12; -- name: MonthlyCostForTeam :many -WITH last_run AS ( - SELECT MAX(date)::date AS "last_run" - FROM cost -) -SELECT - team_slug, - date_trunc('month', date)::date AS month, - -- Extract last day of known cost samples for the month, or the last recorded date - -- This helps with estimation etc - MAX(CASE - WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' - ELSE date_trunc('day', last_run) - END)::date AS last_recorded_date, - SUM(daily_cost)::real AS daily_cost -FROM cost c -LEFT JOIN last_run ON true -WHERE c.team_slug = @team_slug::slug -GROUP BY team_slug, month +SELECT * +FROM cost_monthly_team +WHERE team_slug = @team_slug::slug ORDER BY month DESC LIMIT 12; @@ -92,19 +60,12 @@ ORDER BY -- DailyEnvCostForTeam will fetch the daily cost for a specific team and environment across all apps in a date range. -- name: DailyEnvCostForTeam :many -SELECT - team_slug, - app, - date, - SUM(daily_cost)::real AS daily_cost -FROM - cost +SELECT * +FROM cost_daily_team WHERE date >= @from_date::date AND date <= @to_date::date - AND environment = @environment AND team_slug = @team_slug::slug -GROUP BY - team_slug, app, date + AND environment = @environment ORDER BY date, app ASC; diff --git a/internal/database/queries/resourceusage.sql b/internal/database/queries/resourceusage.sql index 1f7a1bb2c..f894daa49 100644 --- a/internal/database/queries/resourceusage.sql +++ b/internal/database/queries/resourceusage.sql @@ -1,25 +1,20 @@ -- ResourceUtilizationRangeForTeam will return the min and max timestamps for a specific team. -- name: ResourceUtilizationRangeForTeam :one -WITH team_range AS ( - SELECT timestamp - FROM - resource_utilization_metrics - WHERE - team_slug = @team_slug -) SELECT - MIN(timestamp)::timestamptz AS "from", - MAX(timestamp)::timestamptz AS "to" + "from", + "to" FROM - team_range; + resource_team_range +WHERE + team_slug = @team_slug; -- ResourceUtilizationRangeForApp will return the min and max timestamps for a specific app. -- name: ResourceUtilizationRangeForApp :one SELECT - MIN(timestamp)::timestamptz AS "from", - MAX(timestamp)::timestamptz AS "to" + "from", + "to" FROM - resource_utilization_metrics + resource_app_range WHERE environment = @environment AND team_slug = @team_slug @@ -73,19 +68,17 @@ ORDER BY -- ResourceUtilizationForTeam will return resource utilization records for a given team. -- name: ResourceUtilizationForTeam :many SELECT - SUM(usage)::double precision AS usage, - SUM(request)::double precision AS request, + usage, + request, timestamp FROM - resource_utilization_metrics + resource_utilization_team WHERE environment = @environment AND team_slug = @team_slug AND resource_type = @resource_type AND timestamp >= @start::timestamptz AND timestamp < sqlc.arg('end')::timestamptz -GROUP BY - timestamp ORDER BY timestamp ASC; @@ -112,7 +105,7 @@ SELECT SUM(request)::double precision AS request, timestamp FROM - resource_utilization_metrics + resource_utilization_team WHERE team_slug = @team_slug AND resource_type = @resource_type @@ -124,10 +117,10 @@ GROUP BY -- AverageResourceUtilizationForTeam will return the average resource utilization for a team for a week. -- name: AverageResourceUtilizationForTeam :one SELECT - (SUM(usage) / 24 / 7)::double precision AS usage, - (SUM(request) / 24 / 7)::double precision AS request + (SUM(usage)::double precision / 24 / 7)::double precision AS usage, + (SUM(request)::double precision / 24 / 7)::double precision AS request FROM - resource_utilization_metrics + resource_utilization_team WHERE team_slug = @team_slug AND resource_type = @resource_type diff --git a/internal/graph/cost.go b/internal/graph/cost.go index a398b232b..4ac162f8b 100644 --- a/internal/graph/cost.go +++ b/internal/graph/cost.go @@ -48,7 +48,7 @@ func DailyCostsForTeamFromDatabaseRows(from, to scalar.Date, rows []*gensql.Cost return normalizeDailyCosts(from, to, daily), sum } -func DailyCostsForTeamPerEnvFromDatabaseRows(from, to scalar.Date, rows []*gensql.DailyEnvCostForTeamRow) (SortedDailyCosts, float64) { +func DailyCostsForTeamPerEnvFromDatabaseRows(from, to scalar.Date, rows []*gensql.CostDailyTeam) (SortedDailyCosts, float64) { sum := 0.0 daily := DailyCosts{} for _, row := range rows { From 952ac2288306553ef6bdb59960a51ccbe49dcc5e Mon Sep 17 00:00:00 2001 From: Thomas Krampl Date: Mon, 11 Mar 2024 12:08:26 +0100 Subject: [PATCH 2/2] Smaller updates [skip ci] --- internal/database/gensql/cost.sql.go | 77 ------------------- internal/database/gensql/querier.go | 60 --------------- .../migrations/0004_cost_mat_views.sql | 4 +- .../migrations/0005_resource_mat_views.sql | 7 +- 4 files changed, 7 insertions(+), 141 deletions(-) diff --git a/internal/database/gensql/cost.sql.go b/internal/database/gensql/cost.sql.go index 4155ff65e..3d8562c82 100644 --- a/internal/database/gensql/cost.sql.go +++ b/internal/database/gensql/cost.sql.go @@ -137,31 +137,6 @@ type DailyEnvCostForTeamParams struct { } // DailyEnvCostForTeam will fetch the daily cost for a specific team and environment across all apps in a date range. -// SELECT -// -// team_slug, -// app, -// date, -// SUM(daily_cost)::real AS daily_cost -// -// FROM -// -// cost -// -// WHERE -// -// date >= @from_date::date -// AND date <= @to_date::date -// AND environment = @environment -// AND team_slug = @team_slug::slug -// -// GROUP BY -// -// team_slug, app, date -// -// ORDER BY -// -// date, app ASC; func (q *Queries) DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*CostDailyTeam, error) { rows, err := q.db.Query(ctx, dailyEnvCostForTeam, arg.FromDate, @@ -224,34 +199,6 @@ type MonthlyCostForAppParams struct { Environment string } -// WITH last_run AS ( -// -// SELECT MAX(date)::date AS "last_run" -// FROM cost -// -// ) -// SELECT -// -// team_slug, -// app, -// environment, -// date_trunc('month', date)::date AS month, -// -- Extract last day of known cost samples for the month, or the last recorded date -// -- This helps with estimation etc -// MAX(CASE -// WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' -// ELSE date_trunc('day', last_run) -// END)::date AS last_recorded_date, -// SUM(daily_cost)::real AS daily_cost -// -// FROM cost c -// LEFT JOIN last_run ON true -// WHERE c.team_slug = @team_slug::slug -// AND c.app = @app -// AND c.environment = @environment::text -// GROUP BY team_slug, app, environment, month -// ORDER BY month DESC -// LIMIT 12; func (q *Queries) MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*CostMonthlyApp, error) { rows, err := q.db.Query(ctx, monthlyCostForApp, arg.TeamSlug, arg.App, arg.Environment) if err != nil { @@ -287,30 +234,6 @@ ORDER BY month DESC LIMIT 12 ` -// WITH last_run AS ( -// -// SELECT MAX(date)::date AS "last_run" -// FROM cost -// -// ) -// SELECT -// -// team_slug, -// date_trunc('month', date)::date AS month, -// -- Extract last day of known cost samples for the month, or the last recorded date -// -- This helps with estimation etc -// MAX(CASE -// WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' -// ELSE date_trunc('day', last_run) -// END)::date AS last_recorded_date, -// SUM(daily_cost)::real AS daily_cost -// -// FROM cost c -// LEFT JOIN last_run ON true -// WHERE c.team_slug = @team_slug::slug -// GROUP BY team_slug, month -// ORDER BY month DESC -// LIMIT 12; func (q *Queries) MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*CostMonthlyTeam, error) { rows, err := q.db.Query(ctx, monthlyCostForTeam, teamSlug) if err != nil { diff --git a/internal/database/gensql/querier.go b/internal/database/gensql/querier.go index 90d774b4d..56e4079c3 100644 --- a/internal/database/gensql/querier.go +++ b/internal/database/gensql/querier.go @@ -39,22 +39,6 @@ type Querier interface { // DailyCostForTeam will fetch the daily cost for a specific team across all apps and envs in a date range. DailyCostForTeam(ctx context.Context, arg DailyCostForTeamParams) ([]*Cost, error) // DailyEnvCostForTeam will fetch the daily cost for a specific team and environment across all apps in a date range. - // SELECT - // team_slug, - // app, - // date, - // SUM(daily_cost)::real AS daily_cost - // FROM - // cost - // WHERE - // date >= @from_date::date - // AND date <= @to_date::date - // AND environment = @environment - // AND team_slug = @team_slug::slug - // GROUP BY - // team_slug, app, date - // ORDER BY - // date, app ASC; DailyEnvCostForTeam(ctx context.Context, arg DailyEnvCostForTeamParams) ([]*CostDailyTeam, error) // DailyVulnerabilityForTeam will return the metrics for the given team from first to last date. DailyVulnerabilityForTeam(ctx context.Context, arg DailyVulnerabilityForTeamParams) ([]*DailyVulnerabilityForTeamRow, error) @@ -127,51 +111,7 @@ type Querier interface { ListRepositoriesByAuthorization(ctx context.Context, arg ListRepositoriesByAuthorizationParams) ([]string, error) // MaxResourceUtilizationDate will return the max date for resource utilization records. MaxResourceUtilizationDate(ctx context.Context) (pgtype.Timestamptz, error) - // WITH last_run AS ( - // SELECT MAX(date)::date AS "last_run" - // FROM cost - // ) - // SELECT - // team_slug, - // app, - // environment, - // date_trunc('month', date)::date AS month, - // -- Extract last day of known cost samples for the month, or the last recorded date - // -- This helps with estimation etc - // MAX(CASE - // WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' - // ELSE date_trunc('day', last_run) - // END)::date AS last_recorded_date, - // SUM(daily_cost)::real AS daily_cost - // FROM cost c - // LEFT JOIN last_run ON true - // WHERE c.team_slug = @team_slug::slug - // AND c.app = @app - // AND c.environment = @environment::text - // GROUP BY team_slug, app, environment, month - // ORDER BY month DESC - // LIMIT 12; MonthlyCostForApp(ctx context.Context, arg MonthlyCostForAppParams) ([]*CostMonthlyApp, error) - // WITH last_run AS ( - // SELECT MAX(date)::date AS "last_run" - // FROM cost - // ) - // SELECT - // team_slug, - // date_trunc('month', date)::date AS month, - // -- Extract last day of known cost samples for the month, or the last recorded date - // -- This helps with estimation etc - // MAX(CASE - // WHEN date_trunc('month', date) < date_trunc('month', last_run) THEN date_trunc('month', date) + interval '1 month' - interval '1 day' - // ELSE date_trunc('day', last_run) - // END)::date AS last_recorded_date, - // SUM(daily_cost)::real AS daily_cost - // FROM cost c - // LEFT JOIN last_run ON true - // WHERE c.team_slug = @team_slug::slug - // GROUP BY team_slug, month - // ORDER BY month DESC - // LIMIT 12; MonthlyCostForTeam(ctx context.Context, teamSlug slug.Slug) ([]*CostMonthlyTeam, error) RemoveAllServiceAccountRoles(ctx context.Context, serviceAccountID uuid.UUID) error RemoveApiKeysFromServiceAccount(ctx context.Context, serviceAccountID uuid.UUID) error diff --git a/internal/database/migrations/0004_cost_mat_views.sql b/internal/database/migrations/0004_cost_mat_views.sql index e3c3bb58a..92eaa0641 100644 --- a/internal/database/migrations/0004_cost_mat_views.sql +++ b/internal/database/migrations/0004_cost_mat_views.sql @@ -24,7 +24,7 @@ GROUP BY team_slug, month ORDER BY month DESC ; -CREATE INDEX ON cost_monthly_team (team_slug, month); +CREATE INDEX ON cost_monthly_team (month DESC, team_slug); -- Monthly per app @@ -52,7 +52,7 @@ GROUP BY team_slug, app, environment, month ORDER BY month DESC ; -CREATE INDEX ON cost_monthly_app (team_slug, app, environment, month); +CREATE INDEX ON cost_monthly_app (environment, team_slug, app, month DESC); -- Daily per team diff --git a/internal/database/migrations/0005_resource_mat_views.sql b/internal/database/migrations/0005_resource_mat_views.sql index 6860b0b05..84de2bfa5 100644 --- a/internal/database/migrations/0005_resource_mat_views.sql +++ b/internal/database/migrations/0005_resource_mat_views.sql @@ -1,6 +1,7 @@ -- +goose Up -- Team range for resource utilization +DROP MATERIALIZED VIEW IF EXISTS resource_team_range; CREATE MATERIALIZED VIEW resource_team_range AS SELECT team_slug, @@ -14,6 +15,7 @@ GROUP BY CREATE INDEX ON resource_team_range (team_slug); -- App range for resource utilization +DROP MATERIALIZED VIEW IF EXISTS resource_app_range; CREATE MATERIALIZED VIEW resource_app_range AS SELECT team_slug, @@ -26,10 +28,11 @@ FROM GROUP BY team_slug, app, environment; -CREATE INDEX ON resource_app_range (team_slug, app, environment); +CREATE INDEX ON resource_app_range (environment, team_slug, app); -- Resource utilization for team +DROP MATERIALIZED VIEW IF EXISTS resource_utilization_team; CREATE MATERIALIZED VIEW resource_utilization_team AS SELECT team_slug, @@ -43,4 +46,4 @@ FROM GROUP BY team_slug, environment, resource_type, timestamp; -CREATE INDEX ON resource_utilization_team (team_slug, environment, resource_type, timestamp); +CREATE INDEX ON resource_utilization_team (timestamp DESC, team_slug, environment, resource_type);