package db import ( "context" "database/sql" "fmt" "strings" "vctp/db/queries" "github.com/jmoiron/sqlx" ) // SnapshotTotals summarizes counts and allocations for snapshot tables. type SnapshotTotals struct { VmCount int64 `db:"vm_count"` VcpuTotal int64 `db:"vcpu_total"` RamTotal int64 `db:"ram_total"` DiskTotal float64 `db:"disk_total"` } type ColumnDef struct { Name string Type string } // ValidateTableName ensures table identifiers are safe for interpolation. func ValidateTableName(name string) error { if name == "" { return fmt.Errorf("table name is empty") } for _, r := range name { if (r >= 'a' && r <= 'z') || (r >= '0' && r <= '9') || r == '_' { continue } return fmt.Errorf("invalid table name: %s", name) } return nil } // SafeTableName returns the name if it passes validation. func SafeTableName(name string) (string, error) { if err := ValidateTableName(name); err != nil { return "", err } return name, nil } // TableHasRows returns true when a table contains at least one row. func TableHasRows(ctx context.Context, dbConn *sqlx.DB, table string) (bool, error) { if err := ValidateTableName(table); err != nil { return false, err } query := fmt.Sprintf(`SELECT 1 FROM %s LIMIT 1`, table) var exists int if err := dbConn.GetContext(ctx, &exists, query); err != nil { if err == sql.ErrNoRows { return false, nil } return false, err } return true, nil } // TableExists checks if a table exists in the current schema. func TableExists(ctx context.Context, dbConn *sqlx.DB, table string) bool { driver := strings.ToLower(dbConn.DriverName()) switch driver { case "sqlite": q := queries.New(dbConn) count, err := q.SqliteTableExists(ctx, sql.NullString{String: table, Valid: table != ""}) return err == nil && count > 0 case "pgx", "postgres": var count int err := dbConn.GetContext(ctx, &count, ` SELECT COUNT(1) FROM pg_catalog.pg_tables WHERE schemaname = 'public' AND tablename = $1 `, table) return err == nil && count > 0 default: return false } } // ColumnExists checks if a column exists in a table. func ColumnExists(ctx context.Context, dbConn *sqlx.DB, tableName string, columnName string) (bool, error) { driver := strings.ToLower(dbConn.DriverName()) switch driver { case "sqlite": if _, err := SafeTableName(tableName); err != nil { return false, err } 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) } } // SnapshotTotalsForTable returns totals for a snapshot table. func SnapshotTotalsForTable(ctx context.Context, dbConn *sqlx.DB, table string) (SnapshotTotals, error) { if _, err := SafeTableName(table); err != nil { return SnapshotTotals{}, err } 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(CASE WHEN "ProvisionedDisk" IS NOT NULL THEN "ProvisionedDisk" ELSE 0 END), 0) AS disk_total FROM %s WHERE "IsPresent" = 'TRUE' `, table) var totals SnapshotTotals if err := dbConn.GetContext(ctx, &totals, query); err != nil { return SnapshotTotals{}, err } return totals, nil } // SnapshotTotalsForUnion returns totals for a union query of snapshots. func SnapshotTotalsForUnion(ctx context.Context, dbConn *sqlx.DB, unionQuery string) (SnapshotTotals, error) { 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(CASE WHEN "ProvisionedDisk" IS NOT NULL THEN "ProvisionedDisk" ELSE 0 END), 0) AS disk_total FROM ( %s ) snapshots WHERE "IsPresent" = 'TRUE' `, unionQuery) var totals SnapshotTotals if err := dbConn.GetContext(ctx, &totals, query); err != nil { return SnapshotTotals{}, err } return totals, nil } // EnsureSnapshotTable creates a snapshot table with the standard schema if it does not exist. func EnsureSnapshotTable(ctx context.Context, dbConn *sqlx.DB, tableName string) error { if _, err := SafeTableName(tableName); err != nil { return err } 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, "VmId" TEXT, "EventKey" TEXT, "CloudId" TEXT, "CreationTime" BIGINT, "DeletionTime" BIGINT, "ResourcePool" 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) 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, "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) } _, err := dbConn.ExecContext(ctx, ddl) return err } // BackfillSerialColumn sets missing values in a serial-like column for Postgres tables. func BackfillSerialColumn(ctx context.Context, dbConn *sqlx.DB, tableName, columnName string) error { if err := ValidateTableName(tableName); err != nil { return err } if columnName == "" { return fmt.Errorf("column name is empty") } query := fmt.Sprintf( `UPDATE %s SET "%s" = nextval(pg_get_serial_sequence('%s','%s')) WHERE "%s" IS NULL`, tableName, columnName, tableName, columnName, columnName, ) _, err := dbConn.ExecContext(ctx, query) if err != nil { errText := strings.ToLower(err.Error()) if strings.Contains(errText, "pg_get_serial_sequence") || strings.Contains(errText, "sequence") { return nil } return err } return nil } // BuildDailySummaryInsert returns the SQL to aggregate hourly snapshots into a daily summary table. func BuildDailySummaryInsert(tableName string, unionQuery string) (string, error) { if _, err := SafeTableName(tableName); err != nil { return "", err } insert := fmt.Sprintf(` WITH snapshots AS ( %s ) INSERT INTO %s ( "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", "CreationTime", "DeletionTime", "ResourcePool", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid", "SamplesPresent", "AvgVcpuCount", "AvgRamGB", "AvgProvisionedDisk", "AvgIsPresent", "PoolTinPct", "PoolBronzePct", "PoolSilverPct", "PoolGoldPct", "Tin", "Bronze", "Silver", "Gold" ) SELECT "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", COALESCE(NULLIF("CreationTime", 0), MIN(CASE WHEN "IsPresent" = 'TRUE' THEN "SnapshotTime" END), 0) AS "CreationTime", "DeletionTime", ( SELECT s2."ResourcePool" FROM snapshots s2 WHERE s2."VmId" = snapshots."VmId" AND s2."Vcenter" = snapshots."Vcenter" AND s2."IsPresent" = 'TRUE' ORDER BY s2."SnapshotTime" DESC LIMIT 1 ) AS "ResourcePool", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid", SUM(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END) AS "SamplesPresent", AVG(CASE WHEN "IsPresent" = 'TRUE' AND "VcpuCount" IS NOT NULL THEN "VcpuCount" END) AS "AvgVcpuCount", AVG(CASE WHEN "IsPresent" = 'TRUE' AND "RamGB" IS NOT NULL THEN "RamGB" END) AS "AvgRamGB", AVG(CASE WHEN "IsPresent" = 'TRUE' AND "ProvisionedDisk" IS NOT NULL THEN "ProvisionedDisk" END) AS "AvgProvisionedDisk", AVG(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END) AS "AvgIsPresent", 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 "PoolTinPct", 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 "PoolBronzePct", 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", 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 snapshots GROUP BY "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", "CreationTime", "DeletionTime", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid"; `, unionQuery, tableName) return insert, nil } // BuildMonthlySummaryInsert returns the SQL to aggregate daily summaries into a monthly summary table. func BuildMonthlySummaryInsert(tableName string, unionQuery string) (string, error) { if _, err := SafeTableName(tableName); err != nil { return "", err } insert := fmt.Sprintf(` WITH snapshots AS ( %s ) INSERT INTO %s ( "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", "CreationTime", "DeletionTime", "ResourcePool", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid", "AvgVcpuCount", "AvgRamGB", "AvgProvisionedDisk", "AvgIsPresent", "PoolTinPct", "PoolBronzePct", "PoolSilverPct", "PoolGoldPct", "Tin", "Bronze", "Silver", "Gold" ) SELECT "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", "CreationTime", "DeletionTime", ( SELECT s2."ResourcePool" FROM snapshots s2 WHERE s2."VmId" = snapshots."VmId" AND s2."Vcenter" = snapshots."Vcenter" AND s2."IsPresent" = 'TRUE' ORDER BY s2."SnapshotTime" DESC LIMIT 1 ) AS "ResourcePool", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid", AVG(CASE WHEN "VcpuCount" IS NOT NULL THEN "VcpuCount" END) AS "AvgVcpuCount", AVG(CASE WHEN "RamGB" IS NOT NULL THEN "RamGB" END) AS "AvgRamGB", AVG(CASE WHEN "ProvisionedDisk" IS NOT NULL THEN "ProvisionedDisk" END) AS "AvgProvisionedDisk", AVG(CASE WHEN "IsPresent" = 'TRUE' THEN 1 ELSE 0 END) AS "AvgIsPresent", 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 "PoolTinPct", 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 "PoolBronzePct", 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", 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 snapshots GROUP BY "InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId", "CreationTime", "DeletionTime", "Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount", "RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid"; `, unionQuery, tableName) return insert, nil } // EnsureSummaryTable creates a daily/monthly summary table with the standard schema if it does not exist. func EnsureSummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName string) error { if _, err := SafeTableName(tableName); err != nil { return err } 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, "VmId" TEXT, "EventKey" TEXT, "CloudId" TEXT, "CreationTime" BIGINT, "DeletionTime" BIGINT, "ResourcePool" 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) 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, "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) } _, err := dbConn.ExecContext(ctx, ddl) return err }