consolidate raw sql queries [CI_SKIP]
All checks were successful
continuous-integration/drone/push Build is passing
All checks were successful
continuous-integration/drone/push Build is passing
This commit is contained in:
278
db/helpers.go
278
db/helpers.go
@@ -19,6 +19,11 @@ type SnapshotTotals struct {
|
||||
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 == "" {
|
||||
@@ -167,3 +172,276 @@ WHERE "IsPresent" = 'TRUE'
|
||||
}
|
||||
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
|
||||
}
|
||||
|
||||
// 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
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user