diff --git a/internal/report/snapshots.go b/internal/report/snapshots.go index b417782..7283fb9 100644 --- a/internal/report/snapshots.go +++ b/internal/report/snapshots.go @@ -420,7 +420,11 @@ func CreateTableReport(logger *slog.Logger, Database db.Database, ctx context.Co return nil, fmt.Errorf("no columns found for table %s", tableName) } - humanizeTimes := strings.HasPrefix(tableName, "inventory_daily_summary_") || strings.HasPrefix(tableName, "inventory_monthly_summary_") + isHourlySnapshot := strings.HasPrefix(tableName, "inventory_hourly_") + isDailySummary := strings.HasPrefix(tableName, "inventory_daily_summary_") + isMonthlySummary := strings.HasPrefix(tableName, "inventory_monthly_summary_") + hideInventoryID := isHourlySnapshot || isDailySummary || isMonthlySummary + humanizeTimes := isDailySummary || isMonthlySummary type columnSpec struct { Name string SourceIndex int @@ -428,6 +432,9 @@ func CreateTableReport(logger *slog.Logger, Database db.Database, ctx context.Co } specs := make([]columnSpec, 0, len(columns)+2) for i, columnName := range columns { + if hideInventoryID && strings.EqualFold(columnName, "InventoryId") { + continue + } specs = append(specs, columnSpec{Name: columnName, SourceIndex: i}) if humanizeTimes && columnName == "CreationTime" { specs = append(specs, columnSpec{Name: "CreationTimeReadable", SourceIndex: i, Humanize: true}) @@ -521,12 +528,59 @@ func CreateTableReport(logger *slog.Logger, Database db.Database, ctx context.Co logger.Error("Error freezing top row", "error", err) } + addTotalsChartSheet(logger, Database, ctx, xlsx, tableName) + if err := xlsx.Write(&buffer); err != nil { return nil, err } return buffer.Bytes(), nil } +func addTotalsChartSheet(logger *slog.Logger, database db.Database, ctx context.Context, xlsx *excelize.File, tableName string) { + if strings.HasPrefix(tableName, "inventory_daily_summary_") { + suffix := strings.TrimPrefix(tableName, "inventory_daily_summary_") + dayStart, err := time.Parse("20060102", suffix) + if err != nil { + return + } + dayEnd := dayStart.AddDate(0, 0, 1) + if err := EnsureSnapshotRegistry(ctx, database); err != nil { + return + } + records, err := ListSnapshotsByRange(ctx, database, "hourly", dayStart, dayEnd) + if err != nil || len(records) == 0 { + return + } + points, err := buildHourlyTotals(ctx, database.DB(), records) + if err != nil || len(points) == 0 { + return + } + writeTotalsChart(logger, xlsx, "Hourly Totals", points) + return + } + + if strings.HasPrefix(tableName, "inventory_monthly_summary_") { + suffix := strings.TrimPrefix(tableName, "inventory_monthly_summary_") + monthStart, err := time.Parse("200601", suffix) + if err != nil { + return + } + monthEnd := monthStart.AddDate(0, 1, 0) + if err := EnsureSnapshotRegistry(ctx, database); err != nil { + return + } + records, err := ListSnapshotsByRange(ctx, database, "daily", monthStart, monthEnd) + if err != nil || len(records) == 0 { + return + } + points, err := buildDailyTotals(ctx, database.DB(), records) + if err != nil || len(points) == 0 { + return + } + writeTotalsChart(logger, xlsx, "Daily Totals", points) + } +} + func validateTableName(name string) error { if name == "" { return fmt.Errorf("table name is empty") @@ -639,6 +693,163 @@ func normalizeCellValue(value interface{}) interface{} { } } +type totalsPoint struct { + Label string + VmCount int64 + VcpuTotal float64 + RamTotal float64 + PresenceRatio float64 + TinTotal float64 + BronzeTotal float64 + SilverTotal float64 + GoldTotal float64 +} + +func buildHourlyTotals(ctx context.Context, dbConn *sqlx.DB, records []SnapshotRecord) ([]totalsPoint, error) { + points := make([]totalsPoint, 0, len(records)) + for _, record := range records { + if err := validateTableName(record.TableName); err != nil { + return nil, err + } + query := fmt.Sprintf(` +SELECT + COUNT(DISTINCT "VmId") AS vm_count, + COALESCE(SUM(CASE WHEN "IsPresent" = 'TRUE' AND "VcpuCount" IS NOT NULL THEN "VcpuCount" ELSE 0 END), 0) AS vcpu_total, + COALESCE(SUM(CASE WHEN "IsPresent" = 'TRUE' AND "RamGB" IS NOT NULL THEN "RamGB" ELSE 0 END), 0) AS ram_total, + COALESCE(AVG(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS presence_ratio, + COALESCE(SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'tin' THEN 1 ELSE 0 END), 0) AS tin_total, + COALESCE(SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'bronze' THEN 1 ELSE 0 END), 0) AS bronze_total, + COALESCE(SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN 1 ELSE 0 END), 0) AS silver_total, + COALESCE(SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN 1 ELSE 0 END), 0) AS gold_total +FROM %s +`, record.TableName) + 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"` + } + if err := dbConn.GetContext(ctx, &row, query); err != nil { + return nil, err + } + points = append(points, totalsPoint{ + Label: record.SnapshotTime.Local().Format("2006-01-02 15:04"), + VmCount: row.VmCount, + VcpuTotal: float64(row.VcpuTotal), + RamTotal: float64(row.RamTotal), + PresenceRatio: row.PresenceRatio, + TinTotal: row.TinTotal, + BronzeTotal: row.BronzeTotal, + SilverTotal: row.SilverTotal, + GoldTotal: row.GoldTotal, + }) + } + return points, nil +} + +func buildDailyTotals(ctx context.Context, dbConn *sqlx.DB, records []SnapshotRecord) ([]totalsPoint, error) { + points := make([]totalsPoint, 0, len(records)) + for _, record := range records { + if err := validateTableName(record.TableName); err != nil { + return nil, err + } + query := fmt.Sprintf(` +SELECT + COUNT(DISTINCT "VmId") AS vm_count, + COALESCE(SUM(CASE WHEN "AvgVcpuCount" IS NOT NULL THEN "AvgVcpuCount" ELSE 0 END), 0) AS vcpu_total, + COALESCE(SUM(CASE WHEN "AvgRamGB" IS NOT NULL THEN "AvgRamGB" ELSE 0 END), 0) AS ram_total, + COALESCE(AVG(CASE WHEN "AvgIsPresent" IS NOT NULL THEN "AvgIsPresent" ELSE 0 END), 0) AS presence_ratio, + COALESCE(SUM(CASE WHEN "Tin" IS NOT NULL THEN "Tin" ELSE 0 END) / 100.0, 0) AS tin_total, + COALESCE(SUM(CASE WHEN "Bronze" IS NOT NULL THEN "Bronze" ELSE 0 END) / 100.0, 0) AS bronze_total, + COALESCE(SUM(CASE WHEN "Silver" IS NOT NULL THEN "Silver" ELSE 0 END) / 100.0, 0) AS silver_total, + COALESCE(SUM(CASE WHEN "Gold" IS NOT NULL THEN "Gold" ELSE 0 END) / 100.0, 0) AS gold_total +FROM %s +`, record.TableName) + var row struct { + VmCount int64 `db:"vm_count"` + VcpuTotal float64 `db:"vcpu_total"` + RamTotal float64 `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"` + } + if err := dbConn.GetContext(ctx, &row, query); err != nil { + return nil, err + } + points = append(points, totalsPoint{ + Label: record.SnapshotTime.Local().Format("2006-01-02"), + VmCount: row.VmCount, + VcpuTotal: row.VcpuTotal, + RamTotal: row.RamTotal, + PresenceRatio: row.PresenceRatio, + TinTotal: row.TinTotal, + BronzeTotal: row.BronzeTotal, + SilverTotal: row.SilverTotal, + GoldTotal: row.GoldTotal, + }) + } + return points, nil +} + +func writeTotalsChart(logger *slog.Logger, xlsx *excelize.File, sheetName string, points []totalsPoint) { + if len(points) == 0 { + return + } + index := xlsx.NewSheet(sheetName) + xlsx.SetActiveSheet(index) + + headers := []string{"Label", "VmCount", "VcpuCount", "RamGB", "PresenceRatio", "Tin", "Bronze", "Silver", "Gold"} + for i, header := range headers { + cell, _ := excelize.CoordinatesToCellName(i+1, 1) + xlsx.SetCellValue(sheetName, cell, header) + } + for i, point := range points { + row := i + 2 + xlsx.SetCellValue(sheetName, fmt.Sprintf("A%d", row), point.Label) + xlsx.SetCellValue(sheetName, fmt.Sprintf("B%d", row), point.VmCount) + xlsx.SetCellValue(sheetName, fmt.Sprintf("C%d", row), point.VcpuTotal) + xlsx.SetCellValue(sheetName, fmt.Sprintf("D%d", row), point.RamTotal) + xlsx.SetCellValue(sheetName, fmt.Sprintf("E%d", row), point.PresenceRatio) + xlsx.SetCellValue(sheetName, fmt.Sprintf("F%d", row), point.TinTotal) + xlsx.SetCellValue(sheetName, fmt.Sprintf("G%d", row), point.BronzeTotal) + xlsx.SetCellValue(sheetName, fmt.Sprintf("H%d", row), point.SilverTotal) + xlsx.SetCellValue(sheetName, fmt.Sprintf("I%d", row), point.GoldTotal) + } + + lastRow := len(points) + 1 + chart := fmt.Sprintf(`{ + "type": "line", + "series": [ + {"name": "%s!$B$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$B$2:$B$%d"}, + {"name": "%s!$C$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$C$2:$C$%d"}, + {"name": "%s!$D$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$D$2:$D$%d"}, + {"name": "%s!$E$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$E$2:$E$%d"}, + {"name": "%s!$F$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$F$2:$F$%d"}, + {"name": "%s!$G$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$G$2:$G$%d"}, + {"name": "%s!$H$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$H$2:$H$%d"}, + {"name": "%s!$I$1", "categories": "%s!$A$2:$A$%d", "values": "%s!$I$2:$I$%d"} + ], + "legend": {"position": "bottom"} +}`, sheetName, sheetName, lastRow, sheetName, lastRow, + sheetName, sheetName, lastRow, sheetName, lastRow, + sheetName, sheetName, lastRow, sheetName, lastRow, + sheetName, sheetName, lastRow, sheetName, lastRow, + sheetName, sheetName, lastRow, sheetName, lastRow, + sheetName, sheetName, lastRow, sheetName, lastRow, + sheetName, sheetName, lastRow, sheetName, lastRow, + sheetName, sheetName, lastRow, sheetName, lastRow) + + if err := xlsx.AddChart(sheetName, "G2", chart); err != nil { + logger.Error("Error adding totals chart", "error", err) + } +} + func formatEpochHuman(value interface{}) string { var epoch int64 switch v := value.(type) { diff --git a/internal/tasks/inventorySnapshots.go b/internal/tasks/inventorySnapshots.go index 42fd5e4..e237611 100644 --- a/internal/tasks/inventorySnapshots.go +++ b/internal/tasks/inventorySnapshots.go @@ -234,7 +234,8 @@ INSERT INTO %s ( "ResourcePool", "VmType", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid", "SamplesPresent", "AvgVcpuCount", "AvgRamGB", "AvgProvisionedDisk", "AvgIsPresent", - "PoolTinPct", "PoolBronzePct", "PoolSilverPct", "PoolGoldPct" + "PoolTinPct", "PoolBronzePct", "PoolSilverPct", "PoolGoldPct", + "Tin", "Bronze", "Silver", "Gold" ) SELECT "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", "CreationTime", "DeletionTime", @@ -252,7 +253,15 @@ SELECT 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN 1 ELSE 0 END) / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "PoolSilverPct", 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN 1 ELSE 0 END) - / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "PoolGoldPct" + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "PoolGoldPct", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'tin' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Tin", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'bronze' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Bronze", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Silver", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Gold" FROM ( %s ) snapshots @@ -364,7 +373,8 @@ INSERT INTO %s ( "ResourcePool", "VmType", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid", "AvgVcpuCount", "AvgRamGB", "AvgProvisionedDisk", "AvgIsPresent", - "PoolTinPct", "PoolBronzePct", "PoolSilverPct", "PoolGoldPct" + "PoolTinPct", "PoolBronzePct", "PoolSilverPct", "PoolGoldPct", + "Tin", "Bronze", "Silver", "Gold" ) SELECT "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", "CreationTime", "DeletionTime", @@ -381,7 +391,15 @@ SELECT 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN 1 ELSE 0 END) / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "PoolSilverPct", 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN 1 ELSE 0 END) - / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "PoolGoldPct" + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "PoolGoldPct", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'tin' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Tin", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'bronze' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Bronze", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Silver", + 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN 1 ELSE 0 END) + / NULLIF(SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END), 0) AS "Gold" FROM ( %s ) snapshots @@ -498,7 +516,12 @@ func safeTableName(name string) (string, error) { } func ensureDailyInventoryTable(ctx context.Context, dbConn *sqlx.DB, tableName string) error { - ddl := fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + driver := strings.ToLower(dbConn.DriverName()) + var ddl string + switch driver { + case "pgx", "postgres": + ddl = fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + "RowId" BIGSERIAL PRIMARY KEY, "InventoryId" BIGINT, "Name" TEXT NOT NULL, "Vcenter" TEXT NOT NULL, @@ -522,10 +545,40 @@ func ensureDailyInventoryTable(ctx context.Context, dbConn *sqlx.DB, tableName s "SnapshotTime" BIGINT NOT NULL, "IsPresent" TEXT NOT NULL );`, tableName) + default: + ddl = fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + "RowId" INTEGER PRIMARY KEY AUTOINCREMENT, + "InventoryId" BIGINT, + "Name" TEXT NOT NULL, + "Vcenter" TEXT NOT NULL, + "VmId" TEXT, + "EventKey" TEXT, + "CloudId" TEXT, + "CreationTime" BIGINT, + "DeletionTime" BIGINT, + "ResourcePool" TEXT, + "VmType" TEXT, + "Datacenter" TEXT, + "Cluster" TEXT, + "Folder" TEXT, + "ProvisionedDisk" REAL, + "VcpuCount" BIGINT, + "RamGB" BIGINT, + "IsTemplate" TEXT, + "PoweredOn" TEXT, + "SrmPlaceholder" TEXT, + "VmUuid" TEXT, + "SnapshotTime" BIGINT NOT NULL, + "IsPresent" TEXT NOT NULL +);`, tableName) + } if _, err := dbConn.ExecContext(ctx, ddl); err != nil { return err } + if err := ensureSnapshotRowID(ctx, dbConn, tableName); err != nil { + return err + } return ensureSnapshotColumns(ctx, dbConn, tableName, []columnDef{ {Name: "VcpuCount", Type: "BIGINT"}, @@ -534,7 +587,12 @@ func ensureDailyInventoryTable(ctx context.Context, dbConn *sqlx.DB, tableName s } func ensureDailySummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName string) error { - ddl := fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + driver := strings.ToLower(dbConn.DriverName()) + var ddl string + switch driver { + case "pgx", "postgres": + ddl = fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + "RowId" BIGSERIAL PRIMARY KEY, "InventoryId" BIGINT, "Name" TEXT NOT NULL, "Vcenter" TEXT NOT NULL, @@ -563,12 +621,57 @@ func ensureDailySummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName str "PoolTinPct" REAL, "PoolBronzePct" REAL, "PoolSilverPct" REAL, - "PoolGoldPct" REAL + "PoolGoldPct" REAL, + "Tin" REAL, + "Bronze" REAL, + "Silver" REAL, + "Gold" REAL );`, tableName) + default: + ddl = fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + "RowId" INTEGER PRIMARY KEY AUTOINCREMENT, + "InventoryId" BIGINT, + "Name" TEXT NOT NULL, + "Vcenter" TEXT NOT NULL, + "VmId" TEXT, + "EventKey" TEXT, + "CloudId" TEXT, + "CreationTime" BIGINT, + "DeletionTime" BIGINT, + "ResourcePool" TEXT, + "VmType" TEXT, + "Datacenter" TEXT, + "Cluster" TEXT, + "Folder" TEXT, + "ProvisionedDisk" REAL, + "VcpuCount" BIGINT, + "RamGB" BIGINT, + "IsTemplate" TEXT, + "PoweredOn" TEXT, + "SrmPlaceholder" TEXT, + "VmUuid" TEXT, + "SamplesPresent" BIGINT NOT NULL, + "AvgVcpuCount" REAL, + "AvgRamGB" REAL, + "AvgProvisionedDisk" REAL, + "AvgIsPresent" REAL, + "PoolTinPct" REAL, + "PoolBronzePct" REAL, + "PoolSilverPct" REAL, + "PoolGoldPct" REAL, + "Tin" REAL, + "Bronze" REAL, + "Silver" REAL, + "Gold" REAL +);`, tableName) + } if _, err := dbConn.ExecContext(ctx, ddl); err != nil { return err } + if err := ensureSnapshotRowID(ctx, dbConn, tableName); err != nil { + return err + } return ensureSnapshotColumns(ctx, dbConn, tableName, []columnDef{ {Name: "AvgVcpuCount", Type: "REAL"}, @@ -579,11 +682,20 @@ func ensureDailySummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName str {Name: "PoolBronzePct", Type: "REAL"}, {Name: "PoolSilverPct", Type: "REAL"}, {Name: "PoolGoldPct", Type: "REAL"}, + {Name: "Tin", Type: "REAL"}, + {Name: "Bronze", Type: "REAL"}, + {Name: "Silver", Type: "REAL"}, + {Name: "Gold", Type: "REAL"}, }) } func ensureMonthlySummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName string) error { - ddl := fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + driver := strings.ToLower(dbConn.DriverName()) + var ddl string + switch driver { + case "pgx", "postgres": + ddl = fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + "RowId" BIGSERIAL PRIMARY KEY, "InventoryId" BIGINT, "Name" TEXT NOT NULL, "Vcenter" TEXT NOT NULL, @@ -611,12 +723,56 @@ func ensureMonthlySummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName s "PoolTinPct" REAL, "PoolBronzePct" REAL, "PoolSilverPct" REAL, - "PoolGoldPct" REAL + "PoolGoldPct" REAL, + "Tin" REAL, + "Bronze" REAL, + "Silver" REAL, + "Gold" REAL );`, tableName) + default: + ddl = fmt.Sprintf(`CREATE TABLE IF NOT EXISTS %s ( + "RowId" INTEGER PRIMARY KEY AUTOINCREMENT, + "InventoryId" BIGINT, + "Name" TEXT NOT NULL, + "Vcenter" TEXT NOT NULL, + "VmId" TEXT, + "EventKey" TEXT, + "CloudId" TEXT, + "CreationTime" BIGINT, + "DeletionTime" BIGINT, + "ResourcePool" TEXT, + "VmType" TEXT, + "Datacenter" TEXT, + "Cluster" TEXT, + "Folder" TEXT, + "ProvisionedDisk" REAL, + "VcpuCount" BIGINT, + "RamGB" BIGINT, + "IsTemplate" TEXT, + "PoweredOn" TEXT, + "SrmPlaceholder" TEXT, + "VmUuid" TEXT, + "AvgVcpuCount" REAL, + "AvgRamGB" REAL, + "AvgProvisionedDisk" REAL, + "AvgIsPresent" REAL, + "PoolTinPct" REAL, + "PoolBronzePct" REAL, + "PoolSilverPct" REAL, + "PoolGoldPct" REAL, + "Tin" REAL, + "Bronze" REAL, + "Silver" REAL, + "Gold" REAL +);`, tableName) + } if _, err := dbConn.ExecContext(ctx, ddl); err != nil { return err } + if err := ensureSnapshotRowID(ctx, dbConn, tableName); err != nil { + return err + } return ensureSnapshotColumns(ctx, dbConn, tableName, []columnDef{ {Name: "AvgVcpuCount", Type: "REAL"}, @@ -627,6 +783,10 @@ func ensureMonthlySummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName s {Name: "PoolBronzePct", Type: "REAL"}, {Name: "PoolSilverPct", Type: "REAL"}, {Name: "PoolGoldPct", Type: "REAL"}, + {Name: "Tin", Type: "REAL"}, + {Name: "Bronze", Type: "REAL"}, + {Name: "Silver", Type: "REAL"}, + {Name: "Gold", Type: "REAL"}, }) } @@ -735,6 +895,79 @@ func addColumnIfMissing(ctx context.Context, dbConn *sqlx.DB, tableName string, return nil } +func ensureSnapshotRowID(ctx context.Context, dbConn *sqlx.DB, tableName string) error { + driver := strings.ToLower(dbConn.DriverName()) + switch driver { + case "pgx", "postgres": + hasColumn, err := columnExists(ctx, dbConn, tableName, "RowId") + if err != nil { + return err + } + if !hasColumn { + if err := addColumnIfMissing(ctx, dbConn, tableName, columnDef{Name: "RowId", Type: "BIGSERIAL"}); err != nil { + return err + } + } + _, err = dbConn.ExecContext(ctx, fmt.Sprintf( + `UPDATE %s SET "RowId" = nextval(pg_get_serial_sequence('%s','RowId')) WHERE "RowId" IS NULL`, + tableName, tableName, + )) + if err != nil { + errText := strings.ToLower(err.Error()) + if strings.Contains(errText, "pg_get_serial_sequence") || strings.Contains(errText, "sequence") { + return nil + } + return err + } + case "sqlite": + return nil + } + return nil +} + +func columnExists(ctx context.Context, dbConn *sqlx.DB, tableName string, columnName string) (bool, error) { + driver := strings.ToLower(dbConn.DriverName()) + switch driver { + case "sqlite": + query := fmt.Sprintf(`PRAGMA table_info("%s")`, tableName) + rows, err := dbConn.QueryxContext(ctx, query) + if err != nil { + return false, err + } + defer rows.Close() + for rows.Next() { + var ( + cid int + name string + colType string + notNull int + defaultVal sql.NullString + pk int + ) + if err := rows.Scan(&cid, &name, &colType, ¬Null, &defaultVal, &pk); err != nil { + return false, err + } + if strings.EqualFold(name, columnName) { + return true, nil + } + } + return false, rows.Err() + case "pgx", "postgres": + var count int + err := dbConn.GetContext(ctx, &count, ` +SELECT COUNT(1) +FROM information_schema.columns +WHERE table_name = $1 AND column_name = $2 +`, tableName, strings.ToLower(columnName)) + if err != nil { + return false, err + } + return count > 0, nil + default: + return false, fmt.Errorf("unsupported driver for column lookup: %s", driver) + } +} + func snapshotTotalsForTable(ctx context.Context, dbConn *sqlx.DB, table string) (snapshotTotals, error) { if _, err := safeTableName(table); err != nil { return snapshotTotals{}, err