Files
vctp2/db/helpers.go
Nathan Coad 50e9921955
All checks were successful
continuous-integration/drone/push Build is passing
improve aggregations
2026-01-15 09:57:05 +11:00

685 lines
25 KiB
Go

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
}
// TableRowCount returns COUNT(*) for a table.
func TableRowCount(ctx context.Context, dbConn *sqlx.DB, table string) (int64, error) {
if err := ValidateTableName(table); err != nil {
return 0, err
}
var count int64
query := fmt.Sprintf(`SELECT COUNT(*) FROM %s`, table)
if err := dbConn.GetContext(ctx, &count, query); err != nil {
return 0, err
}
return count, nil
}
// EnsureColumns adds the provided columns to a table if they are missing.
func EnsureColumns(ctx context.Context, dbConn *sqlx.DB, tableName string, columns []ColumnDef) error {
if _, err := SafeTableName(tableName); err != nil {
return err
}
for _, column := range columns {
if err := AddColumnIfMissing(ctx, dbConn, tableName, column); err != nil {
return err
}
}
return nil
}
// AddColumnIfMissing performs a best-effort ALTER TABLE to add a column, ignoring "already exists".
func AddColumnIfMissing(ctx context.Context, dbConn *sqlx.DB, tableName string, column ColumnDef) error {
if _, err := SafeTableName(tableName); err != nil {
return err
}
query := fmt.Sprintf(`ALTER TABLE %s ADD COLUMN "%s" %s`, tableName, column.Name, column.Type)
if _, err := dbConn.ExecContext(ctx, query); err != nil {
errText := strings.ToLower(err.Error())
if strings.Contains(errText, "duplicate column") || strings.Contains(errText, "already exists") {
return nil
}
return err
}
return nil
}
// 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, &notNull, &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)
if err != nil {
return err
}
indexes := []string{
fmt.Sprintf(`CREATE INDEX IF NOT EXISTS %s_vm_vcenter_idx ON %s ("VmId","Vcenter")`, tableName, tableName),
fmt.Sprintf(`CREATE INDEX IF NOT EXISTS %s_snapshottime_idx ON %s ("SnapshotTime")`, tableName, tableName),
fmt.Sprintf(`CREATE INDEX IF NOT EXISTS %s_resourcepool_idx ON %s ("ResourcePool")`, tableName, tableName),
}
for _, idx := range indexes {
if _, err := dbConn.ExecContext(ctx, idx); err != nil {
return err
}
}
return nil
}
// 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
}
// ApplySQLiteTuning applies lightweight WAL/synchronous tweaks for better concurrency in non-prod contexts.
func ApplySQLiteTuning(ctx context.Context, dbConn *sqlx.DB) {
if strings.ToLower(dbConn.DriverName()) != "sqlite" {
return
}
// Best-effort pragmas; ignore errors to stay safe in constrained environments.
pragmas := []string{
`PRAGMA journal_mode=WAL;`,
`PRAGMA synchronous=NORMAL;`,
`PRAGMA temp_store=MEMORY;`,
}
for _, pragma := range pragmas {
_, _ = dbConn.ExecContext(ctx, pragma)
}
}
// CheckMigrationState ensures goose migrations are present and not dirty.
func CheckMigrationState(ctx context.Context, dbConn *sqlx.DB) error {
driver := strings.ToLower(dbConn.DriverName())
var tableExists bool
switch driver {
case "sqlite":
err := dbConn.GetContext(ctx, &tableExists, `
SELECT COUNT(1) > 0 FROM sqlite_master WHERE type='table' AND name='goose_db_version'
`)
if err != nil {
return err
}
case "pgx", "postgres":
err := dbConn.GetContext(ctx, &tableExists, `
SELECT EXISTS (
SELECT 1 FROM pg_tables WHERE schemaname = 'public' AND tablename = 'goose_db_version'
)
`)
if err != nil {
return err
}
default:
return fmt.Errorf("unsupported driver for migration check: %s", driver)
}
if !tableExists {
return fmt.Errorf("goose_db_version table not found; database migrations may not be applied")
}
var dirty bool
err := dbConn.GetContext(ctx, &dirty, `
SELECT NOT is_applied
FROM goose_db_version
ORDER BY id DESC
LIMIT 1
`)
if err != nil {
return err
}
if dirty {
return fmt.Errorf("database migrations are in a dirty state; please resolve goose_db_version")
}
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
), ordered AS (
SELECT
s.*,
LEAD("SnapshotTime") OVER (PARTITION BY "VmId", "Vcenter" ORDER BY "SnapshotTime") AS next_snapshot,
LEAD("SnapshotTime") OVER (PARTITION BY "VmId", "Vcenter" ORDER BY "SnapshotTime") - "SnapshotTime" AS interval_seconds
FROM snapshots s
), weighted AS (
SELECT
o.*,
CASE
WHEN o.interval_seconds IS NULL OR o.interval_seconds <= 0 THEN 3600
ELSE o.interval_seconds
END AS weight_seconds
FROM ordered o
)
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",
COALESCE(NULLIF("DeletionTime", 0), MAX(CASE WHEN "IsPresent" = 'TRUE' THEN "SnapshotTime" END), 0) AS "DeletionTime",
(
SELECT s2."ResourcePool"
FROM weighted s2
WHERE s2."VmId" = weighted."VmId"
AND s2."Vcenter" = weighted."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",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' AND "VcpuCount" IS NOT NULL THEN "VcpuCount" * weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "AvgVcpuCount",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' AND "RamGB" IS NOT NULL THEN "RamGB" * weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "AvgRamGB",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' AND "ProvisionedDisk" IS NOT NULL THEN "ProvisionedDisk" * weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "AvgProvisionedDisk",
CASE WHEN SUM(weight_seconds) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) / SUM(weight_seconds)
ELSE NULL END AS "AvgIsPresent",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'tin' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolTinPct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'bronze' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolBronzePct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolSilverPct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolGoldPct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'tin' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Tin",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'bronze' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Bronze",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Silver",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Gold"
FROM weighted
GROUP BY
"InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId",
"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
), ordered AS (
SELECT
s.*,
LEAD("SnapshotTime") OVER (PARTITION BY "VmId", "Vcenter" ORDER BY "SnapshotTime") AS next_snapshot,
LEAD("SnapshotTime") OVER (PARTITION BY "VmId", "Vcenter" ORDER BY "SnapshotTime") - "SnapshotTime" AS interval_seconds
FROM snapshots s
), weighted AS (
SELECT
o.*,
CASE
WHEN o.interval_seconds IS NULL OR o.interval_seconds <= 0 THEN 3600
ELSE o.interval_seconds
END AS weight_seconds
FROM ordered o
)
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",
COALESCE(NULLIF("DeletionTime", 0), MAX(CASE WHEN "IsPresent" = 'TRUE' THEN "SnapshotTime" END), 0) AS "DeletionTime",
(
SELECT s2."ResourcePool"
FROM weighted s2
WHERE s2."VmId" = weighted."VmId"
AND s2."Vcenter" = weighted."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",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' AND "VcpuCount" IS NOT NULL THEN "VcpuCount" * weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "AvgVcpuCount",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' AND "RamGB" IS NOT NULL THEN "RamGB" * weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "AvgRamGB",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' AND "ProvisionedDisk" IS NOT NULL THEN "ProvisionedDisk" * weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "AvgProvisionedDisk",
CASE WHEN SUM(weight_seconds) > 0
THEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) / SUM(weight_seconds)
ELSE NULL END AS "AvgIsPresent",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'tin' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolTinPct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'bronze' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolBronzePct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolSilverPct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "PoolGoldPct",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'tin' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Tin",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'bronze' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Bronze",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'silver' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Silver",
CASE WHEN SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END) > 0
THEN 100.0 * SUM(CASE WHEN "IsPresent" = 'TRUE' AND LOWER("ResourcePool") = 'gold' THEN weight_seconds ELSE 0 END)
/ SUM(CASE WHEN "IsPresent" = 'TRUE' THEN weight_seconds ELSE 0 END)
ELSE NULL END AS "Gold"
FROM weighted
GROUP BY
"InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId",
"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)
}
if _, err := dbConn.ExecContext(ctx, ddl); err != nil {
return err
}
indexes := []string{
fmt.Sprintf(`CREATE INDEX IF NOT EXISTS %s_vm_vcenter_idx ON %s ("VmId","Vcenter")`, tableName, tableName),
fmt.Sprintf(`CREATE INDEX IF NOT EXISTS %s_resourcepool_idx ON %s ("ResourcePool")`, tableName, tableName),
}
for _, idx := range indexes {
if _, err := dbConn.ExecContext(ctx, idx); err != nil {
return err
}
}
return nil
}