Skip to content

Commit

Permalink
exp/ticker: optimize global market aggregation query (#1168)
Browse files Browse the repository at this point in the history
  • Loading branch information
accordeiro authored Apr 24, 2019
1 parent b29f97d commit 43c62a5
Show file tree
Hide file tree
Showing 2 changed files with 58 additions and 107 deletions.
159 changes: 55 additions & 104 deletions exp/ticker/internal/tickerdb/queries_market.go
Original file line number Diff line number Diff line change
Expand Up @@ -93,113 +93,64 @@ func (s *TickerSession) RetrievePartialMarkets(

var marketQuery = `
SELECT
t2.trade_pair_name as trade_pair_name,
COALESCE(t1.base_volume_24h, 0.0) as base_volume_24h,
COALESCE(t1.counter_volume_24h, 0.0) as counter_volume_24h,
COALESCE(t1.trade_count_24h, 0) as trade_count_24h,
COALESCE(t1.highest_price_24h, 0.0) as highest_price_24h,
COALESCE(t1.lowest_price_24h, 0.0) as lowest_price_24h,
COALESCE(t4.price_24h_ago - last_price, 0.0) as price_change_24h,
COALESCE(t4.price_24h_ago, 0.0) as open_price_24h,
COALESCE(t2.base_volume_7d, 0) as base_volume_7d,
COALESCE(t2.counter_volume_7d, 0) as counter_volume_7d,
COALESCE(t2.trade_count_7d, 0) as trade_count_7d,
COALESCE(t2.highest_price_7d, 0.0) as highest_price_7d,
COALESCE(t2.lowest_price_7d, 0.0) as lowest_price_7d,
COALESCE(t5.price_7d_ago - last_price, 0.0) as price_change_7d,
COALESCE(t5.price_7d_ago, 0.0) as open_price_7d,
COALESCE(t3.last_price, 0.0) as last_price,
COALESCE(t3.last_close_time, now()) as close_time
t2.trade_pair_name,
COALESCE(base_volume_24h, 0.0) as base_volume_24h,
COALESCE(counter_volume_24h, 0.0) as counter_volume_24h,
COALESCE(trade_count_24h, 0) as trade_count_24h,
COALESCE(highest_price_24h, 0.0) as highest_price_24h,
COALESCE(lowest_price_24h, 0.0) as lowest_price_24h,
COALESCE(price_change_24h, 0.0) as price_change_24h,
COALESCE(open_price_24h, 0.0) as open_price_24h,
COALESCE(base_volume_7d, 0) as base_volume_7d,
COALESCE(counter_volume_7d, 0) as counter_volume_7d,
COALESCE(trade_count_7d, 0) as trade_count_7d,
COALESCE(highest_price_7d, 0.0) as highest_price_7d,
COALESCE(lowest_price_7d, 0.0) as lowest_price_7d,
COALESCE(price_change_7d, 0.0) as price_change_7d,
COALESCE(open_price_7d, 0.0) as open_price_7d,
COALESCE(last_price, 0.0) as last_price,
COALESCE(last_close_time, now()) as close_time
FROM (
-- All trades between valid assets in the last 24h aggregated:
SELECT
concat(bAsset.code, '_', cAsset.code) as trade_pair_name,
sum(t.base_amount) as base_volume_24h,
sum(t.counter_amount) as counter_volume_24h,
max(t.price) as highest_price_24h,
min(t.price) as lowest_price_24h,
count(t.base_amount) as trade_count_24h
FROM trades as t
JOIN assets as bAsset
ON t.base_asset_id = bAsset.id
JOIN assets as cAsset
ON t.counter_asset_id = cAsset.id
WHERE bAsset.is_valid = TRUE
AND cAsset.is_valid = TRUE
AND t.ledger_close_time > now() - interval '1 day'
GROUP BY trade_pair_name
) t1
FULL JOIN (
-- All trades between valid assets in the last 7d aggregated:
-- All valid trades for 24h period
concat(bAsset.code, '_', cAsset.code) as trade_pair_name,
sum(t.base_amount) AS base_volume_24h,
sum(t.counter_amount) AS counter_volume_24h,
count(t.base_amount) AS trade_count_24h,
max(t.price) AS highest_price_24h,
min(t.price) AS lowest_price_24h,
(array_agg(t.price ORDER BY t.ledger_close_time ASC))[1] AS open_price_24h,
(array_agg(t.price ORDER BY t.ledger_close_time DESC))[1] AS last_price,
((array_agg(t.price ORDER BY t.ledger_close_time DESC))[1] - (array_agg(t.price ORDER BY t.ledger_close_time ASC))[1]) AS price_change_24h,
max(t.ledger_close_time) AS last_close_time
FROM trades AS t
JOIN assets AS bAsset ON t.base_asset_id = bAsset.id
JOIN assets AS cAsset on t.counter_asset_id = cAsset.id
WHERE bAsset.is_valid = TRUE
AND cAsset.is_valid = TRUE
AND t.ledger_close_time > now() - interval '1 day'
GROUP BY trade_pair_name
) t1 RIGHT JOIN (
SELECT
concat(bAsset.code, '_', cAsset.code) as trade_pair_name,
sum(t.base_amount) as base_volume_7d,
sum(t.counter_amount) as counter_volume_7d,
max(t.price) as highest_price_7d,
min(t.price) as lowest_price_7d,
count(t.base_amount) as trade_count_7d
FROM trades as t
JOIN assets as bAsset
ON t.base_asset_id = bAsset.id
JOIN assets as cAsset
ON t.counter_asset_id = cAsset.id
WHERE bAsset.is_valid = TRUE
AND cAsset.is_valid = TRUE
AND t.ledger_close_time > now() - interval '7 days'
GROUP BY trade_pair_name
) t2 ON t1.trade_pair_name = t2.trade_pair_name
INNER JOIN (
-- Last prices and close times:
SELECT DISTINCT ON (trade_pair_name)
concat(bAsset.code, '_', cAsset.code) as trade_pair_name,
t.price as last_price,
t.ledger_close_time as last_close_time
FROM trades as t
JOIN assets as bAsset
ON t.base_asset_id = bAsset.id
JOIN assets as cAsset
ON t.counter_asset_id = cAsset.id
WHERE bAsset.is_valid = TRUE
AND cAsset.is_valid = TRUE
AND t.ledger_close_time > now() - interval '7 days'
ORDER BY trade_pair_name, t.ledger_close_time DESC
) t3 ON t2.trade_pair_name = t3.trade_pair_name
LEFT JOIN (
-- Price 24h ago:
SELECT DISTINCT ON (trade_pair_name)
concat(bAsset.code, '_', cAsset.code) as trade_pair_name,
t.price as price_24h_ago
FROM trades as t
JOIN assets as bAsset
ON t.base_asset_id = bAsset.id
JOIN assets as cAsset
ON t.counter_asset_id = cAsset.id
WHERE bAsset.is_valid = TRUE
AND cAsset.is_valid = TRUE
AND t.ledger_close_time > now() - interval '1 days'
ORDER BY trade_pair_name, t.ledger_close_time ASC
) t4 ON t3.trade_pair_name = t4.trade_pair_name
LEFT JOIN (
-- Price 7d ago:
SELECT DISTINCT ON (trade_pair_name)
concat(bAsset.code, '_', cAsset.code) as trade_pair_name,
t.price as price_7d_ago
FROM trades as t
JOIN assets as bAsset
ON t.base_asset_id = bAsset.id
JOIN assets as cAsset
ON t.counter_asset_id = cAsset.id
WHERE bAsset.is_valid = TRUE
AND cAsset.is_valid = TRUE
AND t.ledger_close_time > now() - interval '7 days'
ORDER BY trade_pair_name, t.ledger_close_time ASC
) t5 ON t4.trade_pair_name = t5.trade_pair_name
ORDER BY trade_pair_name;
-- All valid trades for 7d period
concat(bAsset.code, '_', cAsset.code) as trade_pair_name,
sum(t.base_amount) AS base_volume_7d,
sum(t.counter_amount) AS counter_volume_7d,
count(t.base_amount) AS trade_count_7d,
max(t.price) AS highest_price_7d,
min(t.price) AS lowest_price_7d,
(array_agg(t.price ORDER BY t.ledger_close_time ASC))[1] AS open_price_7d,
((array_agg(t.price ORDER BY t.ledger_close_time DESC))[1] - (array_agg(t.price ORDER BY t.ledger_close_time ASC))[1]) AS price_change_7d
FROM trades AS t
JOIN assets AS bAsset ON t.base_asset_id = bAsset.id
JOIN assets AS cAsset on t.counter_asset_id = cAsset.id
WHERE bAsset.is_valid = TRUE
AND cAsset.is_valid = TRUE
AND t.ledger_close_time > now() - interval '7 days'
GROUP BY trade_pair_name
) t2 ON t1.trade_pair_name = t2.trade_pair_name;
`

var partialMarketQuery = `
Expand Down
6 changes: 3 additions & 3 deletions exp/ticker/internal/tickerdb/queries_market_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -199,7 +199,7 @@ func TestRetrieveMarketData(t *testing.T) {
// There might be some floating point rounding issues, so this test
// needs to be a bit more flexible. Since the change is 0.02, an error
// around 0.0000000000001 is acceptable:
priceChange7dDiff := math.Abs(0.02 - xlmbtcMkt.PriceChange7d)
priceChange7dDiff := math.Abs(-0.02 - xlmbtcMkt.PriceChange7d)
assert.True(t, priceChange7dDiff < 0.0000000000001)

assert.Equal(t, 74.0, xlmethMkt.BaseVolume24h)
Expand All @@ -226,10 +226,10 @@ func TestRetrieveMarketData(t *testing.T) {
// There might be some floating point rounding issues, so this test
// needs to be a bit more flexible. Since the change is 0.08, an error
// around 0.0000000000001 is acceptable:
priceChange24hDiff := math.Abs(-0.08 - xlmethMkt.PriceChange24h)
priceChange24hDiff := math.Abs(0.08 - xlmethMkt.PriceChange24h)
assert.True(t, priceChange24hDiff < 0.0000000000001)

priceChange7dDiff = math.Abs(-0.08 - xlmethMkt.PriceChange7d)
priceChange7dDiff = math.Abs(0.08 - xlmethMkt.PriceChange7d)
assert.True(t, priceChange7dDiff < 0.0000000000001)

assert.Equal(t, priceChange24hDiff, priceChange7dDiff)
Expand Down

0 comments on commit 43c62a5

Please sign in to comment.