From 31242f3820f2ae9b952fd8e84e1633b8b72b31b1 Mon Sep 17 00:00:00 2001 From: Clement Sam Date: Wed, 17 Aug 2022 18:12:26 +0000 Subject: [PATCH] satellite: use table aliases for query in QueryStorageNodeUsage endpoint Following the changes made to fix the storage usage graph on the storagenode dashboard, we added a new interval_end_time column to the accounting_rollups table. We noticed a two-day delay in the graph, turns out the sub-query was wrong due to the conflicting interval_end_time column in both tables so we have to explicitly state which table column we are referring to. Also, set the default for interval_end_time in the accounting rollups to the start_time if the interval_end_time is null which will be removed once we backfill the column and alter it to be a non-nullable column. Updates https://github.com/storj/storj/issues/4178 Change-Id: Iff32b261d07b6ee219d2b6b6542377f0c54633a1 --- .../satellitedb/storagenodeaccounting.go | 35 +++++++++++-------- 1 file changed, 20 insertions(+), 15 deletions(-) diff --git a/satellite/satellitedb/storagenodeaccounting.go b/satellite/satellitedb/storagenodeaccounting.go index 8cf781b91..3f16c7574 100644 --- a/satellite/satellitedb/storagenodeaccounting.go +++ b/satellite/satellitedb/storagenodeaccounting.go @@ -475,25 +475,30 @@ func (db *StoragenodeAccounting) QueryStorageNodeUsage(ctx context.Context, node start, end = start.UTC(), end.UTC() + // TODO: remove COALESCE when we're sure the interval_end_time in the + // accounting_rollups table are fully populated or back-filled with + // the start_time, and the interval_end_time is non-nullable query := ` - SELECT SUM(at_rest_total), (start_time at time zone 'UTC')::date as start_time, MAX(interval_end_time) AS interval_end_time - FROM accounting_rollups - WHERE node_id = $1 - AND $2 <= start_time AND start_time <= $3 - GROUP BY (start_time at time zone 'UTC')::date + SELECT SUM(r1.at_rest_total) as at_rest_total, + (r1.start_time at time zone 'UTC')::date as start_time, + COALESCE(MAX(r1.interval_end_time), MAX(r1.start_time)) AS interval_end_time + FROM accounting_rollups r1 + WHERE r1.node_id = $1 + AND $2 <= r1.start_time AND r1.start_time <= $3 + GROUP BY (r1.start_time at time zone 'UTC')::date UNION - SELECT SUM(data_total) AS at_rest_total, (interval_end_time at time zone 'UTC')::date AS start_time, - MAX(interval_end_time) AS interval_end_time - FROM storagenode_storage_tallies - WHERE node_id = $1 + SELECT SUM(t.data_total) AS at_rest_total, (t.interval_end_time at time zone 'UTC')::date AS start_time, + MAX(t.interval_end_time) AS interval_end_time + FROM storagenode_storage_tallies t + WHERE t.node_id = $1 AND NOT EXISTS ( - SELECT 1 FROM accounting_rollups - WHERE node_id = $1 - AND $2 <= start_time AND start_time <= $3 - AND (start_time at time zone 'UTC')::date = (interval_end_time at time zone 'UTC')::date + SELECT 1 FROM accounting_rollups r2 + WHERE r2.node_id = $1 + AND $2 <= r2.start_time AND r2.start_time <= $3 + AND (r2.start_time at time zone 'UTC')::date = (t.interval_end_time at time zone 'UTC')::date ) - AND (SELECT value FROM accounting_timestamps WHERE name = $4) < interval_end_time AND interval_end_time <= $3 - GROUP BY (interval_end_time at time zone 'UTC')::date + AND (SELECT value FROM accounting_timestamps WHERE name = $4) < t.interval_end_time AND t.interval_end_time <= $3 + GROUP BY (t.interval_end_time at time zone 'UTC')::date ORDER BY start_time; `