From b05d42d07f9dc0c9de4f9c8b01ad3b172d17f3ef Mon Sep 17 00:00:00 2001 From: Felix Leupold Date: Mon, 9 Sep 2024 14:20:54 +0200 Subject: [PATCH 1/4] [CoW AMM Performance] 10k growth for daily rebalancing portfolio --- cow_amm/daily_rebalancing_4055484.sql | 49 +++++++++++++++++++++++++++ 1 file changed, 49 insertions(+) create mode 100644 cow_amm/daily_rebalancing_4055484.sql diff --git a/cow_amm/daily_rebalancing_4055484.sql b/cow_amm/daily_rebalancing_4055484.sql new file mode 100644 index 00000000..732c280b --- /dev/null +++ b/cow_amm/daily_rebalancing_4055484.sql @@ -0,0 +1,49 @@ +-- Computes the balances and current value of a counterfactual portfolio that invests 10k evenly into two tokens and re-balances once a day to keep a 50:50 exposure +-- Parameters +-- {{token_a}} - either token of the desired uni pool +-- {{token_b}} - other token of the desired uni pool +-- {{start}} - date as of which the analysis should run + +with recursive balances (day, balance0, balance1) as ( + -- Base case: $10k are invested evenly into token_a and token_b at the opening price of the start day + select + date(timestamp '{{start}}'), + 10000 / 2 / p1.price_open, -- Initial balance in token_a + 10000 / 2 / p2.price_open -- Initial balance in token_b + from prices.usd_daily as p1 + inner join prices.usd_daily as p2 + on + p1.day = date(timestamp '{{start}}') + and p1.day = p2.day + and p1.blockchain = 'ethereum' + and p2.blockchain = 'ethereum' + and p1.contract_address = {{token_a}} + and p2.contract_address = {{token_b}} + + union all + + -- Recursive case: Compute the next day's balances according to previous day's closing price and reinvest half into each token + select + b.day + interval '1' day, + (balance0 * p1.price_close + balance1 * p2.price_close) / 2 / p1.price_close, -- Updated balance in token_a + (balance0 * p1.price_close + balance1 * p2.price_close) / 2 / p2.price_close -- Updated balance in token_b + from balances as b + inner join prices.usd_daily as p1 + on b.day = p1.day and p1.contract_address = {{token_a}} + inner join prices.usd_daily as p2 + on b.day = p2.day and p2.contract_address = {{token_b}} + where b.day < date(now()) +) + +-- Multiply daily balances with end of day closing price to get current value +select + b.day, + b.balance0, + b.balance1, + (b.balance0 * p1.price_close) + (b.balance1 * p2.price_close) as current_value +from balances as b +inner join prices.usd_daily as p1 + on b.day = p1.day and p1.contract_address = {{token_a}} +inner join prices.usd_daily as p2 + on b.day = p2.day and p2.contract_address = {{token_b}} +order by 1 desc; From e8c823648916f9a2628914153c85976f1fe17676 Mon Sep 17 00:00:00 2001 From: Felix Leupold Date: Tue, 10 Sep 2024 12:41:54 +0200 Subject: [PATCH 2/4] @fhenneke --- cow_amm/daily_rebalancing_4055484.sql | 77 +++++++++++++++------------ 1 file changed, 42 insertions(+), 35 deletions(-) diff --git a/cow_amm/daily_rebalancing_4055484.sql b/cow_amm/daily_rebalancing_4055484.sql index 732c280b..8fcddf29 100644 --- a/cow_amm/daily_rebalancing_4055484.sql +++ b/cow_amm/daily_rebalancing_4055484.sql @@ -4,46 +4,53 @@ -- {{token_b}} - other token of the desired uni pool -- {{start}} - date as of which the analysis should run -with recursive balances (day, balance0, balance1) as ( - -- Base case: $10k are invested evenly into token_a and token_b at the opening price of the start day - select - date(timestamp '{{start}}'), - 10000 / 2 / p1.price_open, -- Initial balance in token_a - 10000 / 2 / p2.price_open -- Initial balance in token_b - from prices.usd_daily as p1 - inner join prices.usd_daily as p2 - on - p1.day = date(timestamp '{{start}}') - and p1.day = p2.day - and p1.blockchain = 'ethereum' - and p2.blockchain = 'ethereum' - and p1.contract_address = {{token_a}} - and p2.contract_address = {{token_b}} +-- Note: not using a simpler recursive approach due to Dune's recursion depth limitation. +-- Current value of initial investment can be computed as the product of cumulative price changes per day, since +-- value(day+1) = value(day) * (p1.price(day+1)/p1.price(day) + p2.price(day+1) / p2.price(day))/2 - union all +-- limit the relevant date range +with date_series as ( + select t.day + from + unnest(sequence( + date(timestamp '{{start}}'), + date(now()) + )) t (day) --noqa: AL01 +), - -- Recursive case: Compute the next day's balances according to previous day's closing price and reinvest half into each token +-- computes relative daily price changes for both assets +daily_price_change as ( select - b.day + interval '1' day, - (balance0 * p1.price_close + balance1 * p2.price_close) / 2 / p1.price_close, -- Updated balance in token_a - (balance0 * p1.price_close + balance1 * p2.price_close) / 2 / p2.price_close -- Updated balance in token_b - from balances as b + ds.day, + p1.price_close / previous_p1.price_close as p1, + p2.price_close / previous_p2.price_close as p2 + from date_series as ds inner join prices.usd_daily as p1 - on b.day = p1.day and p1.contract_address = {{token_a}} + on + p1.day + and p1.contract_address = {{token_a}} + and p1.blockchain = 'ethereum' + inner join prices.usd_daily as previous_p1 + on + previous_p1.day = ds.day - interval '1' day + and previous_p1.contract_address = {{token_a}} + and previous_p1.blockchain = 'ethereum' inner join prices.usd_daily as p2 - on b.day = p2.day and p2.contract_address = {{token_b}} - where b.day < date(now()) + on + p2.day + and p2.contract_address = {{token_b}} + and p2.blockchain = 'ethereum' + inner join prices.usd_daily as previous_p2 + on + previous_p2.day = ds.day - interval '1' day + and previous_p2.contract_address = {{token_b}} + and previous_p2.blockchain = 'ethereum' ) --- Multiply daily balances with end of day closing price to get current value +-- For each day multiply initial investment with cumulative product of average price change of the two assets select - b.day, - b.balance0, - b.balance1, - (b.balance0 * p1.price_close) + (b.balance1 * p2.price_close) as current_value -from balances as b -inner join prices.usd_daily as p1 - on b.day = p1.day and p1.contract_address = {{token_a}} -inner join prices.usd_daily as p2 - on b.day = p2.day and p2.contract_address = {{token_b}} -order by 1 desc; + day, + -- SQL doesn't support PRODUCT() over (...), but luckily "the sum of logarithms" is equal to "logarithm of the product", + exp(sum(ln((p1 + p2) / 2)) over (order by day asc)) * 10000 as current_value +from daily_price_change +order by 1 desc From 788a04f6968fe683db37795551bc64de153d42d6 Mon Sep 17 00:00:00 2001 From: Felix Leupold Date: Tue, 10 Sep 2024 12:43:43 +0200 Subject: [PATCH 3/4] bit more elaboration in the product --- cow_amm/daily_rebalancing_4055484.sql | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/cow_amm/daily_rebalancing_4055484.sql b/cow_amm/daily_rebalancing_4055484.sql index 8fcddf29..8e0bc896 100644 --- a/cow_amm/daily_rebalancing_4055484.sql +++ b/cow_amm/daily_rebalancing_4055484.sql @@ -6,7 +6,9 @@ -- Note: not using a simpler recursive approach due to Dune's recursion depth limitation. -- Current value of initial investment can be computed as the product of cumulative price changes per day, since --- value(day+1) = value(day) * (p1.price(day+1)/p1.price(day) + p2.price(day+1) / p2.price(day))/2 +-- `value(day+1) = value(day) * (p1.price(day+1)/p1.price(day) + p2.price(day+1) / p2.price(day))/2` +-- Thus, current_value can be computed using cumulative products of (sums of) daily price changes: +-- `(p1.price(day+1)/p1.price(day) + p2.price(day+1)/p2.price(day))/2` -- limit the relevant date range with date_series as ( From a7d32be6b55f720856477fc464eb3dd09ed7fedd Mon Sep 17 00:00:00 2001 From: Felix Leupold Date: Tue, 10 Sep 2024 15:48:45 +0200 Subject: [PATCH 4/4] rename final column --- cow_amm/daily_rebalancing_4055484.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/cow_amm/daily_rebalancing_4055484.sql b/cow_amm/daily_rebalancing_4055484.sql index 8e0bc896..9688f770 100644 --- a/cow_amm/daily_rebalancing_4055484.sql +++ b/cow_amm/daily_rebalancing_4055484.sql @@ -53,6 +53,6 @@ daily_price_change as ( select day, -- SQL doesn't support PRODUCT() over (...), but luckily "the sum of logarithms" is equal to "logarithm of the product", - exp(sum(ln((p1 + p2) / 2)) over (order by day asc)) * 10000 as current_value + exp(sum(ln((p1 + p2) / 2)) over (order by day asc)) * 10000 as current_value_of_investment from daily_price_change order by 1 desc