diff --git a/internal/report/snapshots.go b/internal/report/snapshots.go index cfd707c..ef07593 100644 --- a/internal/report/snapshots.go +++ b/internal/report/snapshots.go @@ -1118,37 +1118,84 @@ func buildHourlyTotals(ctx context.Context, logger *slog.Logger, dbConn *sqlx.DB startExpr := `CASE WHEN "CreationTime" IS NOT NULL AND "CreationTime" > 0 AND "CreationTime" > ? THEN "CreationTime" ELSE ? END` endExpr := `CASE WHEN "DeletionTime" IS NOT NULL AND "DeletionTime" > 0 AND "DeletionTime" < ? THEN "DeletionTime" ELSE ? END` overlapExpr := fmt.Sprintf(`CASE WHEN %s > %s THEN (CAST((%s - %s) AS REAL) / ?) ELSE 0 END`, endExpr, startExpr, endExpr, startExpr) + idExpr := `COALESCE(NULLIF("VmId", ''), NULLIF("VmUuid", ''), NULLIF("Name", ''), 'unknown')` + vmKeyExpr := fmt.Sprintf(`(%s || '|' || COALESCE("Vcenter", ''))`, idExpr) query := fmt.Sprintf(` -SELECT - COUNT(DISTINCT "VmId") AS vm_count, - COALESCE(SUM(CASE WHEN "VcpuCount" IS NOT NULL THEN "VcpuCount" ELSE 0 END), 0) AS vcpu_total, - COALESCE(SUM(CASE WHEN "RamGB" IS NOT NULL THEN "RamGB" ELSE 0 END), 0) AS ram_total, - COALESCE(SUM(presence), 0) AS presence_ratio, - COALESCE(SUM(CASE WHEN pool = 'tin' THEN presence ELSE 0 END), 0) AS tin_total, - COALESCE(SUM(CASE WHEN pool = 'bronze' THEN presence ELSE 0 END), 0) AS bronze_total, - COALESCE(SUM(CASE WHEN pool = 'silver' THEN presence ELSE 0 END), 0) AS silver_total, - COALESCE(SUM(CASE WHEN pool = 'gold' THEN presence ELSE 0 END), 0) AS gold_total -FROM ( +WITH base AS ( SELECT + %s AS vm_key, "VmId", + "VmUuid", + "Name", "VcpuCount", "RamGB", LOWER(COALESCE("ResourcePool", '')) AS pool, %s AS presence FROM %s WHERE %s -) t -`, overlapExpr, record.TableName, templateExclusionFilter()) +), +agg AS ( + SELECT + vm_key, + MAX("VcpuCount") AS "VcpuCount", + MAX("RamGB") AS "RamGB", + MAX(pool) AS pool, + MAX(presence) AS presence + FROM base + GROUP BY vm_key +), +diag AS ( + SELECT + COUNT(*) AS row_count, + COUNT(DISTINCT vm_key) AS distinct_keys, + COALESCE(SUM(CASE WHEN vm_key LIKE 'unknown|%%' THEN 1 ELSE 0 END), 0) AS unknown_keys, + COALESCE(SUM(CASE WHEN "VmId" IS NULL OR "VmId" = '' THEN 1 ELSE 0 END), 0) AS missing_vm_id, + COALESCE(SUM(CASE WHEN "VmUuid" IS NULL OR "VmUuid" = '' THEN 1 ELSE 0 END), 0) AS missing_vm_uuid, + COALESCE(SUM(CASE WHEN "Name" IS NULL OR "Name" = '' THEN 1 ELSE 0 END), 0) AS missing_name, + COALESCE(SUM(CASE WHEN presence > 1 THEN 1 ELSE 0 END), 0) AS presence_over_one, + COALESCE(SUM(CASE WHEN presence < 0 THEN 1 ELSE 0 END), 0) AS presence_under_zero, + COALESCE(SUM(presence), 0) AS base_presence_sum + FROM base +) +SELECT + (SELECT COUNT(*) FROM agg) AS vm_count, + (SELECT COALESCE(SUM(CASE WHEN "VcpuCount" IS NOT NULL THEN "VcpuCount" ELSE 0 END), 0) FROM agg) AS vcpu_total, + (SELECT COALESCE(SUM(CASE WHEN "RamGB" IS NOT NULL THEN "RamGB" ELSE 0 END), 0) FROM agg) AS ram_total, + (SELECT COALESCE(SUM(presence), 0) FROM agg) AS presence_ratio, + (SELECT COALESCE(SUM(CASE WHEN pool = 'tin' THEN presence ELSE 0 END), 0) FROM agg) AS tin_total, + (SELECT COALESCE(SUM(CASE WHEN pool = 'bronze' THEN presence ELSE 0 END), 0) FROM agg) AS bronze_total, + (SELECT COALESCE(SUM(CASE WHEN pool = 'silver' THEN presence ELSE 0 END), 0) FROM agg) AS silver_total, + (SELECT COALESCE(SUM(CASE WHEN pool = 'gold' THEN presence ELSE 0 END), 0) FROM agg) AS gold_total, + diag.row_count, + diag.distinct_keys, + diag.unknown_keys, + diag.missing_vm_id, + diag.missing_vm_uuid, + diag.missing_name, + diag.presence_over_one, + diag.presence_under_zero, + diag.base_presence_sum +FROM diag +`, vmKeyExpr, overlapExpr, record.TableName, templateExclusionFilter()) query = dbConn.Rebind(query) var row struct { - VmCount int64 `db:"vm_count"` - VcpuTotal int64 `db:"vcpu_total"` - RamTotal int64 `db:"ram_total"` - PresenceRatio float64 `db:"presence_ratio"` - TinTotal float64 `db:"tin_total"` - BronzeTotal float64 `db:"bronze_total"` - SilverTotal float64 `db:"silver_total"` - GoldTotal float64 `db:"gold_total"` + VmCount int64 `db:"vm_count"` + VcpuTotal int64 `db:"vcpu_total"` + RamTotal int64 `db:"ram_total"` + PresenceRatio float64 `db:"presence_ratio"` + TinTotal float64 `db:"tin_total"` + BronzeTotal float64 `db:"bronze_total"` + SilverTotal float64 `db:"silver_total"` + GoldTotal float64 `db:"gold_total"` + RowCount int64 `db:"row_count"` + DistinctKeys int64 `db:"distinct_keys"` + UnknownKeys int64 `db:"unknown_keys"` + MissingVmID int64 `db:"missing_vm_id"` + MissingVmUUID int64 `db:"missing_vm_uuid"` + MissingName int64 `db:"missing_name"` + PresenceOverOne int64 `db:"presence_over_one"` + PresenceUnderZero int64 `db:"presence_under_zero"` + BasePresenceSum float64 `db:"base_presence_sum"` } args := []interface{}{ hourEndUnix, hourEndUnix, @@ -1160,6 +1207,24 @@ FROM ( if err := dbConn.GetContext(ctx, &row, query, args...); err != nil { return nil, err } + duplicateRows := row.RowCount - row.DistinctKeys + logger.Debug( + "hourly totals snapshot diagnostics", + "table", record.TableName, + "hour_start", hourStart.Format("2006-01-02 15:00"), + "row_count", row.RowCount, + "distinct_keys", row.DistinctKeys, + "duplicate_rows", duplicateRows, + "unknown_keys", row.UnknownKeys, + "missing_vm_id", row.MissingVmID, + "missing_vm_uuid", row.MissingVmUUID, + "missing_name", row.MissingName, + "presence_over_one", row.PresenceOverOne, + "presence_under_zero", row.PresenceUnderZero, + "base_presence_sum", row.BasePresenceSum, + "presence_ratio", row.PresenceRatio, + "vm_count", row.VmCount, + ) hourKey := hourStartUnix bucket := buckets[hourKey] if bucket == nil {