Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add yield token support #156

Merged
merged 9 commits into from
Dec 16, 2024
Merged
Show file tree
Hide file tree
Changes from 8 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -17,137 +17,68 @@ with pnl_hourly as (
hourly_pnl_pct,
hourly_rewards_pct,
hourly_total_pct,
SUM(
COALESCE(
hourly_issuance,
0
)
) over (
partition by
pool_id,
collateral_type
order by
ts
sum(coalesce(hourly_issuance, 0)) over (
partition by pool_id, collateral_type
order by ts
) as cumulative_issuance,
SUM(
hourly_pnl
) over (
partition by
pool_id,
collateral_type
order by
ts
sum(hourly_pnl) over (
partition by pool_id, collateral_type
order by ts
) as cumulative_pnl
from
{{ ref('fct_pool_pnl_hourly_arbitrum_mainnet') }}
from {{ ref('fct_pool_pnl_hourly_arbitrum_mainnet') }}
),

avg_returns as (
select
ts,
pool_id,
collateral_type,
AVG(
hourly_pnl_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '24 HOURS' preceding
and current row
avg(hourly_pnl_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '24 HOURS' preceding and current row
) as avg_24h_pnl_pct,
AVG(
hourly_pnl_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '7 DAYS' preceding
and current row
avg(hourly_pnl_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '7 DAYS' preceding and current row
) as avg_7d_pnl_pct,
AVG(
hourly_pnl_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '28 DAYS' preceding
and current row
avg(hourly_pnl_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '28 DAYS' preceding and current row
) as avg_28d_pnl_pct,
AVG(
hourly_rewards_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '24 HOURS' preceding
and current row
avg(hourly_rewards_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '24 HOURS' preceding and current row
) as avg_24h_rewards_pct,
AVG(
hourly_rewards_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '7 DAYS' preceding
and current row
avg(hourly_rewards_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '7 DAYS' preceding and current row
) as avg_7d_rewards_pct,
AVG(
hourly_rewards_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '28 DAYS' preceding
and current row
avg(hourly_rewards_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '28 DAYS' preceding and current row
) as avg_28d_rewards_pct,
AVG(
hourly_total_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '24 HOURS' preceding
and current row
avg(hourly_total_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '24 HOURS' preceding and current row
) as avg_24h_total_pct,
AVG(
hourly_total_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '7 DAYS' preceding
and current row
avg(hourly_total_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '7 DAYS' preceding and current row
) as avg_7d_total_pct,
AVG(
hourly_total_pct
) over (
partition by
pool_id,
collateral_type
order by
ts
range between interval '28 DAYS' preceding
and current row
avg(hourly_total_pct) over (
partition by pool_id, collateral_type
order by ts
range between interval '28 DAYS' preceding and current row
) as avg_28d_total_pct
from
pnl_hourly
from pnl_hourly
),

apr_calculations as (
Expand Down Expand Up @@ -175,30 +106,40 @@ apr_calculations as (
-- rewards pnls
avg_returns.avg_24h_rewards_pct * 24 * 365 as apr_24h_rewards,
avg_returns.avg_7d_rewards_pct * 24 * 365 as apr_7d_rewards,
avg_returns.avg_28d_rewards_pct * 24 * 365 as apr_28d_rewards
from
pnl_hourly
avg_returns.avg_28d_rewards_pct * 24 * 365 as apr_28d_rewards,
-- underlying yields
coalesce(yr.apr_24h_underlying, 0) as apr_24h_underlying,
coalesce(yr.apr_7d_underlying, 0) as apr_7d_underlying,
coalesce(yr.apr_28d_underlying, 0) as apr_28d_underlying
from pnl_hourly
inner join avg_returns
on
pnl_hourly.ts = avg_returns.ts
and pnl_hourly.pool_id = avg_returns.pool_id
and pnl_hourly.collateral_type = avg_returns.collateral_type
left join {{ ref('fct_token_yields_arbitrum_mainnet') }} as yr
on
pnl_hourly.ts = yr.ts
and pnl_hourly.pool_id = yr.pool_id
and pnl_hourly.collateral_type = yr.collateral_type
),

apy_calculations as (
select
*,
(POWER(1 + apr_24h / 8760, 8760) - 1) as apy_24h,
(POWER(1 + apr_7d / 8760, 8760) - 1) as apy_7d,
(POWER(1 + apr_28d / 8760, 8760) - 1) as apy_28d,
(POWER(1 + apr_24h_pnl / 8760, 8760) - 1) as apy_24h_pnl,
(POWER(1 + apr_7d_pnl / 8760, 8760) - 1) as apy_7d_pnl,
(POWER(1 + apr_28d_pnl / 8760, 8760) - 1) as apy_28d_pnl,
(POWER(1 + apr_24h_rewards / 8760, 8760) - 1) as apy_24h_rewards,
(POWER(1 + apr_7d_rewards / 8760, 8760) - 1) as apy_7d_rewards,
(POWER(1 + apr_28d_rewards / 8760, 8760) - 1) as apy_28d_rewards
from
apr_calculations
(power(1 + apr_24h / 8760, 8760) - 1) as apy_24h,
(power(1 + apr_7d / 8760, 8760) - 1) as apy_7d,
(power(1 + apr_28d / 8760, 8760) - 1) as apy_28d,
(power(1 + apr_24h_pnl / 8760, 8760) - 1) as apy_24h_pnl,
(power(1 + apr_7d_pnl / 8760, 8760) - 1) as apy_7d_pnl,
(power(1 + apr_28d_pnl / 8760, 8760) - 1) as apy_28d_pnl,
(power(1 + apr_24h_rewards / 8760, 8760) - 1) as apy_24h_rewards,
(power(1 + apr_7d_rewards / 8760, 8760) - 1) as apy_7d_rewards,
(power(1 + apr_28d_rewards / 8760, 8760) - 1) as apy_28d_rewards,
(power(1 + apr_24h_underlying / 8760, 8760) - 1) as apy_24h_underlying,
(power(1 + apr_7d_underlying / 8760, 8760) - 1) as apy_7d_underlying,
(power(1 + apr_28d_underlying / 8760, 8760) - 1) as apy_28d_underlying
from apr_calculations
)

select
Expand Down Expand Up @@ -231,8 +172,12 @@ select
apr_7d_rewards,
apy_7d_rewards,
apr_28d_rewards,
apy_28d_rewards
from
apy_calculations
order by
ts
apy_28d_rewards,
apr_24h_underlying,
apy_24h_underlying,
apr_7d_underlying,
apy_7d_underlying,
apr_28d_underlying,
apy_28d_underlying
from apy_calculations
order by ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
with dim as (
select distinct
p.ts,
p.pool_id,
p.collateral_type,
t.token_symbol,
t.yield_token_symbol
from
{{ ref('fct_pool_pnl_hourly_arbitrum_mainnet') }}
as p
inner join
{{ ref('arbitrum_mainnet_tokens') }}
as t
on lower(p.collateral_type) = lower(t.token_address)
where
t.yield_token_symbol is not null
),

token_prices as (
select
dim.ts,
dim.pool_id,
dim.collateral_type,
dim.token_symbol,
dim.yield_token_symbol,
tp.price as token_price,
yp.price as yield_token_price,
tp.price / yp.price as exchange_rate
from
dim
inner join {{ ref('fct_prices_hourly_arbitrum_mainnet') }} as tp
on
dim.token_symbol = tp.market_symbol
and dim.ts = tp.ts
inner join {{ ref('fct_prices_hourly_arbitrum_mainnet') }} as yp
on
dim.yield_token_symbol = yp.market_symbol
and dim.ts = yp.ts
),

rate_changes as (
select
ts,
pool_id,
collateral_type,
exchange_rate,
exchange_rate / lag(exchange_rate) over (
partition by token_symbol, yield_token_symbol
order by
ts
) - 1 as hourly_exchange_rate_pnl
from
token_prices
)

select
ts,
pool_id,
collateral_type,
exchange_rate,
hourly_exchange_rate_pnl,
avg(hourly_exchange_rate_pnl) over (
partition by collateral_type
order by
ts
range between interval '24 HOURS' preceding
and current row
) * 24 * 365 as apr_24h_underlying,
avg(hourly_exchange_rate_pnl) over (
partition by collateral_type
order by
ts
range between interval '7 DAYS' preceding
and current row
) * 24 * 365 as apr_7d_underlying,
avg(hourly_exchange_rate_pnl) over (
partition by collateral_type
order by
ts
range between interval '28 DAYS' preceding
and current row
) * 24 * 365 as apr_28d_underlying
from
rate_changes
Loading
Loading