diff --git a/transformers/synthetix/models/marts/arbitrum/mainnet/core/fct_core_apr_arbitrum_mainnet.sql b/transformers/synthetix/models/marts/arbitrum/mainnet/core/fct_core_apr_arbitrum_mainnet.sql index b442bdcd..86cb0278 100644 --- a/transformers/synthetix/models/marts/arbitrum/mainnet/core/fct_core_apr_arbitrum_mainnet.sql +++ b/transformers/synthetix/models/marts/arbitrum/mainnet/core/fct_core_apr_arbitrum_mainnet.sql @@ -17,29 +17,15 @@ 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 ( @@ -47,107 +33,52 @@ avg_returns as ( 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 ( @@ -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 @@ -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 diff --git a/transformers/synthetix/models/marts/arbitrum/mainnet/core/fct_token_yields_arbitrum_mainnet.sql b/transformers/synthetix/models/marts/arbitrum/mainnet/core/fct_token_yields_arbitrum_mainnet.sql new file mode 100644 index 00000000..408da78d --- /dev/null +++ b/transformers/synthetix/models/marts/arbitrum/mainnet/core/fct_token_yields_arbitrum_mainnet.sql @@ -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 diff --git a/transformers/synthetix/models/marts/arbitrum/mainnet/core/schema.yml b/transformers/synthetix/models/marts/arbitrum/mainnet/core/schema.yml index 0d1c3a8a..82bb5318 100644 --- a/transformers/synthetix/models/marts/arbitrum/mainnet/core/schema.yml +++ b/transformers/synthetix/models/marts/arbitrum/mainnet/core/schema.yml @@ -238,6 +238,18 @@ models: data_type: numeric - name: apy_28d_rewards data_type: numeric + - name: apr_24h_underlying + data_type: numeric + - name: apy_24h_underlying + data_type: numeric + - name: apr_7d_underlying + data_type: numeric + - name: apy_7d_underlying + data_type: numeric + - name: apr_28d_underlying + data_type: numeric + - name: apy_28d_underlying + data_type: numeric - name: fct_core_market_updated_arbitrum_mainnet columns: - name: id @@ -262,7 +274,13 @@ models: tests: - not_null - accepted_values: - values: ["MarketCollateralWithdrawn", "MarketCollateralDeposited", "MarketUsdWithdrawn", "MarketUsdDeposited"] + values: + [ + "MarketCollateralWithdrawn", + "MarketCollateralDeposited", + "MarketUsdWithdrawn", + "MarketUsdDeposited", + ] - name: market_id description: "ID of the market" data_type: numeric @@ -598,3 +616,58 @@ models: - dbt_utils.accepted_range: min_value: 0 inclusive: true + - name: fct_core_yield_metrics_arbitrum_mainnet + description: "Hourly yield metrics including exchange rates and trailing yield percentages" + columns: + - name: ts + description: "Block timestamp" + data_type: timestamp with time zone + tests: + - not_null + + - name: pool_id + description: "ID of the pool" + data_type: numeric + tests: + - not_null + - dbt_utils.accepted_range: + min_value: 0 + inclusive: true + + - name: collateral_type + description: "Type of delegated collateral as an address" + data_type: text + tests: + - not_null + + - name: exchange_rate + description: "Exchange rate between token and yield token (ie ETH and wstETH)" + data_type: numeric + tests: + - not_null + - dbt_utils.accepted_range: + min_value: 0 + + - name: hourly_exchange_rate_pnl + description: "Hourly change in exchange rate" + data_type: numeric + tests: + - not_null + + - name: apr_24h_underlying + description: "Annualized yield percentage based on 24-hour average" + data_type: numeric + tests: + - not_null + + - name: apr_7d_underlying + description: "Annualized yield percentage based on 7-day average" + data_type: numeric + tests: + - not_null + + - name: apr_28d_underlying + description: "Annualized yield percentage based on 28-day average" + data_type: numeric + tests: + - not_null diff --git a/transformers/synthetix/models/marts/base/mainnet/core/fct_core_apr_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/core/fct_core_apr_base_mainnet.sql index 9c29b6dd..5ce2d71a 100644 --- a/transformers/synthetix/models/marts/base/mainnet/core/fct_core_apr_base_mainnet.sql +++ b/transformers/synthetix/models/marts/base/mainnet/core/fct_core_apr_base_mainnet.sql @@ -17,29 +17,15 @@ 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_base_mainnet') }} + from {{ ref('fct_pool_pnl_hourly_base_mainnet') }} ), avg_returns as ( @@ -47,107 +33,52 @@ avg_returns as ( 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 ( @@ -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_base_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 @@ -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 diff --git a/transformers/synthetix/models/marts/base/mainnet/core/fct_token_yields_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/core/fct_token_yields_base_mainnet.sql new file mode 100644 index 00000000..e869b3da --- /dev/null +++ b/transformers/synthetix/models/marts/base/mainnet/core/fct_token_yields_base_mainnet.sql @@ -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_base_mainnet') }} + as p + inner join + {{ ref('base_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_base_mainnet') }} as tp + on + dim.token_symbol = tp.market_symbol + and dim.ts = tp.ts + inner join {{ ref('fct_prices_hourly_base_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 diff --git a/transformers/synthetix/models/marts/base/mainnet/core/schema.yml b/transformers/synthetix/models/marts/base/mainnet/core/schema.yml index c96c477b..0dee5847 100644 --- a/transformers/synthetix/models/marts/base/mainnet/core/schema.yml +++ b/transformers/synthetix/models/marts/base/mainnet/core/schema.yml @@ -280,6 +280,18 @@ models: data_type: numeric - name: apy_28d_rewards data_type: numeric + - name: apr_24h_underlying + data_type: numeric + - name: apy_24h_underlying + data_type: numeric + - name: apr_7d_underlying + data_type: numeric + - name: apy_7d_underlying + data_type: numeric + - name: apr_28d_underlying + data_type: numeric + - name: apy_28d_underlying + data_type: numeric - name: fct_core_market_updated_base_mainnet columns: - name: id @@ -645,3 +657,58 @@ models: - dbt_utils.accepted_range: min_value: 0 inclusive: true + - name: fct_core_yield_metrics_base_mainnet + description: "Hourly yield metrics including exchange rates and trailing yield percentages" + columns: + - name: ts + description: "Block timestamp" + data_type: timestamp with time zone + tests: + - not_null + + - name: pool_id + description: "ID of the pool" + data_type: numeric + tests: + - not_null + - dbt_utils.accepted_range: + min_value: 0 + inclusive: true + + - name: collateral_type + description: "Type of delegated collateral as an address" + data_type: text + tests: + - not_null + + - name: exchange_rate + description: "Exchange rate between token and yield token (ie ETH and wstETH)" + data_type: numeric + tests: + - not_null + - dbt_utils.accepted_range: + min_value: 0 + + - name: hourly_exchange_rate_pnl + description: "Hourly change in exchange rate" + data_type: numeric + tests: + - not_null + + - name: apr_24h_underlying + description: "Annualized yield percentage based on 24-hour average" + data_type: numeric + tests: + - not_null + + - name: apr_7d_underlying + description: "Annualized yield percentage based on 7-day average" + data_type: numeric + tests: + - not_null + + - name: apr_28d_underlying + description: "Annualized yield percentage based on 28-day average" + data_type: numeric + tests: + - not_null diff --git a/transformers/synthetix/models/marts/eth/mainnet/core/fct_core_apr_eth_mainnet.sql b/transformers/synthetix/models/marts/eth/mainnet/core/fct_core_apr_eth_mainnet.sql index 511ed391..03b82cf7 100644 --- a/transformers/synthetix/models/marts/eth/mainnet/core/fct_core_apr_eth_mainnet.sql +++ b/transformers/synthetix/models/marts/eth/mainnet/core/fct_core_apr_eth_mainnet.sql @@ -18,29 +18,15 @@ 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_eth_mainnet') }} + from {{ ref('fct_pool_pnl_hourly_eth_mainnet') }} ), avg_returns as ( @@ -48,107 +34,52 @@ avg_returns as ( 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 ( @@ -177,30 +108,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_eth_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 @@ -234,8 +175,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 diff --git a/transformers/synthetix/models/marts/eth/mainnet/core/fct_token_yields_eth_mainnet.sql b/transformers/synthetix/models/marts/eth/mainnet/core/fct_token_yields_eth_mainnet.sql new file mode 100644 index 00000000..1360dbe2 --- /dev/null +++ b/transformers/synthetix/models/marts/eth/mainnet/core/fct_token_yields_eth_mainnet.sql @@ -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_eth_mainnet') }} + as p + inner join + {{ ref('eth_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_eth_mainnet') }} as tp + on + dim.token_symbol = tp.market_symbol + and dim.ts = tp.ts + inner join {{ ref('fct_prices_hourly_eth_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 diff --git a/transformers/synthetix/models/marts/eth/mainnet/core/schema.yml b/transformers/synthetix/models/marts/eth/mainnet/core/schema.yml index a9cb2ab0..eb21f589 100644 --- a/transformers/synthetix/models/marts/eth/mainnet/core/schema.yml +++ b/transformers/synthetix/models/marts/eth/mainnet/core/schema.yml @@ -243,6 +243,18 @@ models: data_type: numeric - name: apy_28d_rewards data_type: numeric + - name: apr_24h_underlying + data_type: numeric + - name: apy_24h_underlying + data_type: numeric + - name: apr_7d_underlying + data_type: numeric + - name: apy_7d_underlying + data_type: numeric + - name: apr_28d_underlying + data_type: numeric + - name: apy_28d_underlying + data_type: numeric - name: fct_core_market_updated_eth_mainnet columns: - name: id @@ -715,3 +727,59 @@ models: - dbt_utils.accepted_range: min_value: 0 inclusive: true + - name: fct_core_yield_metrics_eth_mainnet + description: "Hourly yield metrics including exchange rates and trailing yield percentages" + columns: + - name: ts + description: "Block timestamp" + data_type: timestamp with time zone + tests: + - not_null + + - name: pool_id + description: "ID of the pool" + data_type: numeric + tests: + - not_null + - dbt_utils.accepted_range: + min_value: 0 + inclusive: true + + - name: collateral_type + description: "Type of delegated collateral as an address" + data_type: text + tests: + - not_null + + - name: exchange_rate + description: "Exchange rate between token and yield token (ie ETH and wstETH)" + data_type: numeric + tests: + - not_null + - dbt_utils.accepted_range: + min_value: 0 + inclusive: true + + - name: hourly_exchange_rate_pnl + description: "Hourly change in exchange rate" + data_type: numeric + tests: + - not_null + + - name: apr_24h_underlying + description: "Annualized yield percentage based on 24-hour average" + data_type: numeric + tests: + - not_null + + - name: apr_7d_underlying + description: "Annualized yield percentage based on 7-day average" + data_type: numeric + tests: + - not_null + + - name: apr_28d_underlying + description: "Annualized yield percentage based on 28-day average" + data_type: numeric + tests: + - not_null diff --git a/transformers/synthetix/seeds/tokens/arbitrum_mainnet_tokens.csv b/transformers/synthetix/seeds/tokens/arbitrum_mainnet_tokens.csv index deab54c4..9c4fdb49 100644 --- a/transformers/synthetix/seeds/tokens/arbitrum_mainnet_tokens.csv +++ b/transformers/synthetix/seeds/tokens/arbitrum_mainnet_tokens.csv @@ -1,8 +1,8 @@ -token_address,token_symbol +token_address,token_symbol,yield_token_symbol 0x82aF49447D8a07e3bd95BD0d56f35241523fBab1,WETH 0x912CE59144191C1204E64559FE8253a0e49E6548,ARB 0xaf88d065e77c8cC2239327C5EDb3A432268e5831,USDC 0x5d3a1Ff2b6BAb83b63cd9AD0787074081a52ef34,USDe -0x35751007a407ca6FEFfE80b3cB397736D2cf4dbe,weETH -0x5979D7b546E38E414F7E9822514be443A4800529,wstETH -0x211Cc4DD073734dA055fbF44a2b4667d5E5fE5d2,sUSDe \ No newline at end of file +0x35751007a407ca6FEFfE80b3cB397736D2cf4dbe,weETH, +0x5979D7b546E38E414F7E9822514be443A4800529,wstETH, +0x211Cc4DD073734dA055fbF44a2b4667d5E5fE5d2,sUSDe,USDe \ No newline at end of file diff --git a/transformers/synthetix/seeds/tokens/base_mainnet_tokens.csv b/transformers/synthetix/seeds/tokens/base_mainnet_tokens.csv index ede95456..14a36952 100644 --- a/transformers/synthetix/seeds/tokens/base_mainnet_tokens.csv +++ b/transformers/synthetix/seeds/tokens/base_mainnet_tokens.csv @@ -1,3 +1,3 @@ -token_address,token_symbol +token_address,token_symbol,yield_token_symbol 0xc74ea762cf06c9151ce074e6a569a5945b6302e7,USDC -0x729ef31d86d31440ecbf49f27f7cd7c16c6616d2,stataUSDC \ No newline at end of file +0x729ef31d86d31440ecbf49f27f7cd7c16c6616d2,stataUSDC,USDC \ No newline at end of file diff --git a/transformers/synthetix/seeds/tokens/eth_mainnet_tokens.csv b/transformers/synthetix/seeds/tokens/eth_mainnet_tokens.csv index 997d8ee0..bc2ec274 100644 --- a/transformers/synthetix/seeds/tokens/eth_mainnet_tokens.csv +++ b/transformers/synthetix/seeds/tokens/eth_mainnet_tokens.csv @@ -1,2 +1,3 @@ -token_address,token_symbol -0xC011a73ee8576Fb46F5E1c5751cA3B9Fe0af2a6F,SNX \ No newline at end of file +token_address,token_symbol,yield_token_symbol +0xC011a73ee8576Fb46F5E1c5751cA3B9Fe0af2a6F,SNX +0x7f39C581F595B53c5cb19bD0b3f8dA6c935E2Ca0,wstETH,ETH \ No newline at end of file