This commit is contained in:
221
db/helpers.go
221
db/helpers.go
@@ -281,9 +281,17 @@ func EnsureSnapshotTable(ctx context.Context, dbConn *sqlx.DB, tableName string)
|
||||
return err
|
||||
}
|
||||
|
||||
index := fmt.Sprintf(`CREATE INDEX IF NOT EXISTS %s_vm_vcenter_idx ON %s ("VmId","Vcenter")`, tableName, tableName)
|
||||
_, err = dbConn.ExecContext(ctx, index)
|
||||
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.
|
||||
@@ -378,6 +386,20 @@ func BuildDailySummaryInsert(tableName string, unionQuery string) (string, error
|
||||
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",
|
||||
@@ -390,12 +412,12 @@ INSERT INTO %s (
|
||||
SELECT
|
||||
"InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId",
|
||||
COALESCE(NULLIF("CreationTime", 0), MIN(CASE WHEN "IsPresent" = 'TRUE' THEN "SnapshotTime" END), 0) AS "CreationTime",
|
||||
"DeletionTime",
|
||||
COALESCE(NULLIF("DeletionTime", 0), MAX(CASE WHEN "IsPresent" = 'TRUE' THEN "SnapshotTime" END), 0) AS "DeletionTime",
|
||||
(
|
||||
SELECT s2."ResourcePool"
|
||||
FROM snapshots s2
|
||||
WHERE s2."VmId" = snapshots."VmId"
|
||||
AND s2."Vcenter" = snapshots."Vcenter"
|
||||
FROM weighted s2
|
||||
WHERE s2."VmId" = weighted."VmId"
|
||||
AND s2."Vcenter" = weighted."Vcenter"
|
||||
AND s2."IsPresent" = 'TRUE'
|
||||
ORDER BY s2."SnapshotTime" DESC
|
||||
LIMIT 1
|
||||
@@ -403,29 +425,56 @@ SELECT
|
||||
"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
|
||||
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", "CreationTime", "DeletionTime",
|
||||
"InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId",
|
||||
"Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount",
|
||||
"RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid";
|
||||
`, unionQuery, tableName)
|
||||
@@ -440,51 +489,95 @@ func BuildMonthlySummaryInsert(tableName string, unionQuery string) (string, 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",
|
||||
"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", "CreationTime", "DeletionTime",
|
||||
"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 snapshots s2
|
||||
WHERE s2."VmId" = snapshots."VmId"
|
||||
AND s2."Vcenter" = snapshots."Vcenter"
|
||||
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",
|
||||
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
|
||||
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", "CreationTime", "DeletionTime",
|
||||
"InventoryId", "Name", "Vcenter", "VmId", "EventKey", "CloudId",
|
||||
"Datacenter", "Cluster", "Folder", "ProvisionedDisk", "VcpuCount",
|
||||
"RamGB", "IsTemplate", "PoweredOn", "SrmPlaceholder", "VmUuid";
|
||||
`, unionQuery, tableName)
|
||||
@@ -574,6 +667,18 @@ func EnsureSummaryTable(ctx context.Context, dbConn *sqlx.DB, tableName string)
|
||||
);`, tableName)
|
||||
}
|
||||
|
||||
_, err := dbConn.ExecContext(ctx, ddl)
|
||||
return err
|
||||
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
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user