diff --git a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_base_mainnet.sql index 732f0c8a..22119d27 100644 --- a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_base_mainnet.sql +++ b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_base_mainnet.sql @@ -4,6 +4,7 @@ ) }} with dim as ( + select p.pool_id, p.collateral_type, @@ -85,22 +86,20 @@ ffill as ( dim.ts, dim.pool_id, dim.collateral_type, - coalesce( - last(debt) over ( - partition by dim.collateral_type, dim.pool_id - order by dim.ts - rows between unbounded preceding and current row - ), - 0 - ) as debt, - coalesce( - last(collateral_value) over ( - partition by dim.collateral_type, dim.pool_id - order by dim.ts - rows between unbounded preceding and current row - ), - 0 - ) as collateral_value + coalesce(last(debt.debt) over ( + partition by dim.collateral_type, dim.pool_id + order by + dim.ts + rows between unbounded preceding + and current row + ), 0) as debt, + coalesce(last(collateral.collateral_value) over ( + partition by dim.collateral_type, dim.pool_id + order by + dim.ts + rows between unbounded preceding + and current row + ), 0) as collateral_value from dim left join debt @@ -131,14 +130,74 @@ hourly_pnl as ( ffill ), +pool_rewards as ( + select + r.ts, + r.pool_id, + r.token_symbol, + pnl.collateral_type, + pnl.collateral_value, + sum( + pnl.collateral_value + ) over ( + partition by + r.ts, + r.pool_id, r.token_symbol + ) as pool_collateral_value, + pnl.collateral_value / sum( + pnl.collateral_value + ) over ( + partition by + r.ts, + r.pool_id, r.token_symbol + ) as collateral_type_share, + r.rewards_usd as pool_rewards, + -- reward share of pool rewards + r.rewards_usd + * ( + pnl.collateral_value + / sum(pnl.collateral_value) + over (partition by r.ts, r.pool_id, r.token_symbol) + ) as rewards_usd + from + ( + select + r.ts, + r.pool_id, + r.token_symbol, + r.rewards_usd + from + {{ ref('fct_pool_rewards_pool_hourly_base_mainnet') }} as r + ) as r + inner join hourly_pnl as pnl + on + r.ts = pnl.ts + and r.pool_id = pnl.pool_id +), + hourly_rewards as ( select ts, pool_id, collateral_type, - rewards_usd + sum(rewards_usd) as rewards_usd from - {{ ref('fct_pool_rewards_hourly_base_mainnet') }} + ( + select + ts, + pool_id, + collateral_type, + rewards_usd + from {{ ref('fct_pool_rewards_token_hourly_base_mainnet') }} + union all + select + ts, + pool_id, + collateral_type, + rewards_usd + from pool_rewards + ) as all_rewards + group by ts, pool_id, collateral_type ), hourly_returns as ( @@ -175,13 +234,15 @@ hourly_returns as ( end as hourly_pnl_pct, case when pnl.collateral_value = 0 then 0 - else - ( - coalesce(rewards.rewards_usd, 0) - + pnl.hourly_pnl - + coalesce(iss.hourly_issuance, 0) + else ( + coalesce( + rewards.rewards_usd, + 0 + ) + pnl.hourly_pnl + coalesce( + iss.hourly_issuance, + 0 ) - / pnl.collateral_value + ) / pnl.collateral_value end as hourly_total_pct from hourly_pnl as pnl @@ -189,7 +250,11 @@ hourly_returns as ( on pnl.ts = rewards.ts and pnl.pool_id = rewards.pool_id - and lower(pnl.collateral_type) = lower(rewards.collateral_type) + and lower( + pnl.collateral_type + ) = lower( + rewards.collateral_type + ) left join issuance as iss on pnl.ts = iss.ts diff --git a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_reward_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_reward_base_mainnet.sql index 82d21fc6..0d339fb6 100644 --- a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_reward_base_mainnet.sql +++ b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_pnl_hourly_reward_base_mainnet.sql @@ -29,7 +29,13 @@ with dim as ( cross join ( select distinct token_symbol from - {{ ref('fct_pool_rewards_token_hourly_base_mainnet') }} + ( + select token_symbol + from {{ ref('fct_pool_rewards_token_hourly_base_mainnet') }} + union all + select token_symbol + from {{ ref('fct_pool_rewards_pool_hourly_base_mainnet') }} + ) as tokens ) as p group by t.ts, @@ -55,6 +61,82 @@ reward_hourly_token as ( pool_id, collateral_type, token_symbol +), + +reward_hourly_pool as ( + select + dim.ts, + dim.pool_id, + dim.collateral_type, + dim.reward_token, + dim.collateral_value, + SUM( + dim.collateral_value + ) over ( + partition by + dim.ts, + dim.pool_id, + dim.reward_token + ) as pool_collateral_value, + dim.collateral_value / SUM( + dim.collateral_value + ) over ( + partition by + dim.ts, + dim.pool_id, + dim.reward_token + ) as collateral_type_share, + r.rewards_usd as pool_rewards, + r.rewards_usd + * ( + dim.collateral_value + / SUM(dim.collateral_value) + over (partition by dim.ts, dim.pool_id, dim.reward_token) + ) as rewards_usd + from + ( + select + r.ts, + r.pool_id, + r.token_symbol, + r.rewards_usd + from + {{ ref('fct_pool_rewards_pool_hourly_base_mainnet') }} as r + ) as r + inner join dim + on + r.ts = dim.ts + and r.pool_id = dim.pool_id + and r.token_symbol = dim.reward_token +), + + +reward_hourly as ( + select + ts, + pool_id, + collateral_type, + reward_token, + SUM(rewards_usd) as rewards_usd + from + ( + select + ts, + pool_id, + collateral_type, + reward_token, + rewards_usd + from reward_hourly_token + union all + select + ts, + pool_id, + collateral_type, + reward_token, + rewards_usd + from reward_hourly_pool + ) as all_rewards + group by ts, pool_id, collateral_type, reward_token ) select @@ -64,22 +146,22 @@ select dim.collateral_value, dim.reward_token, COALESCE( - reward_hourly_token.rewards_usd, + reward_hourly.rewards_usd, 0 ) as rewards_usd, case when dim.collateral_value = 0 then 0 else COALESCE( - reward_hourly_token.rewards_usd, + reward_hourly.rewards_usd, 0 ) / dim.collateral_value end as hourly_rewards_pct from dim -left join reward_hourly_token +left join reward_hourly on - dim.ts = reward_hourly_token.ts - and dim.pool_id = reward_hourly_token.pool_id + dim.ts = reward_hourly.ts + and dim.pool_id = reward_hourly.pool_id and LOWER(dim.collateral_type) - = LOWER(reward_hourly_token.collateral_type) - and dim.reward_token = reward_hourly_token.reward_token + = LOWER(reward_hourly.collateral_type) + and dim.reward_token = reward_hourly.reward_token diff --git a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_hourly_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_hourly_base_mainnet.sql deleted file mode 100644 index c3f43e5a..00000000 --- a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_hourly_base_mainnet.sql +++ /dev/null @@ -1,21 +0,0 @@ -with token_hourly as ( - select - ts, - pool_id, - collateral_type, - rewards_usd - from - {{ ref('fct_pool_rewards_token_hourly_base_mainnet') }} -) - -select - ts, - pool_id, - collateral_type, - SUM(rewards_usd) as rewards_usd -from - token_hourly -group by - ts, - pool_id, - collateral_type diff --git a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_pool_hourly_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_pool_hourly_base_mainnet.sql new file mode 100644 index 00000000..53b7a989 --- /dev/null +++ b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_pool_hourly_base_mainnet.sql @@ -0,0 +1,150 @@ +with dim_collateral as ( + select + m.pool_id, + m.collateral_type, + generate_series( + date_trunc('hour', min(t.min_ts)), + date_trunc('hour', max(t.max_ts)), + '1 hour'::INTERVAL + ) as ts + from + ( + select + min(r.ts_start) as min_ts, + max( + r.ts_start + r.duration * '1 second'::INTERVAL + ) as max_ts + from + {{ ref('fct_pool_rewards_base_mainnet') }} as r + ) as t + cross join ( + select distinct + m.pool_id, + m.collateral_type + from + {{ ref('fct_pool_debt_base_mainnet') }} as m + ) as m + group by + m.pool_id, + m.collateral_type +), + +dim_pool as ( + select distinct + ts, + pool_id + from + dim_collateral +), + +rewards_distributed as ( + select + ts, + pool_id, + distributor, + token_symbol, + amount, + ts_start, + duration + from + {{ ref('fct_pool_rewards_base_mainnet') }} + where + collateral_type = '0x0000000000000000000000000000000000000000' +), + +hourly_distributions as ( + select + dim.ts, + dim.pool_id, + r.distributor, + r.token_symbol, + r.amount, + r.ts_start, + r.duration, + row_number() over ( + partition by + dim.ts, + dim.pool_id, + r.distributor + order by + r.ts_start desc + ) as distributor_index + from + dim_pool as dim + left join rewards_distributed as r + on + dim.pool_id = r.pool_id + and dim.ts + '1 hour'::INTERVAL >= r.ts_start + and dim.ts < r.ts_start + r.duration * '1 second'::INTERVAL + where + r.duration > 0 +), + +streamed_rewards as ( + select + d.ts, + d.pool_id, + d.distributor, + d.token_symbol, + -- get the amount of time distributed this hour + -- use the smaller of those two intervals + -- convert the interval to a number of hours + -- multiply the result by the hourly amount to + -- get the amount distributed this hour + ( + extract( + epoch + from + least( + d.duration / 3600 * '1 hour'::INTERVAL, + least( + d.ts + '1 hour'::INTERVAL - greatest( + d.ts, + d.ts_start + ), + least( + d.ts_start + d.duration * '1 second'::INTERVAL, + d.ts + '1 hour'::INTERVAL + ) - d.ts + ) + ) + ) / 3600 + ) * d.amount / ( + d.duration / 3600 + ) as amount + from + hourly_distributions as d + where + d.distributor_index = 1 +), + +combined as ( + select + r.ts, + r.pool_id, + r.distributor, + r.token_symbol, + r.amount, + p.price + from + streamed_rewards as r + left join {{ ref('fct_prices_hourly_base_mainnet') }} as p + on + r.token_symbol = p.market_symbol + and r.ts = p.ts +) + +select + ts, + pool_id, + token_symbol, + sum(amount) as amount, + sum( + amount * price + ) as rewards_usd +from + combined +group by + ts, + pool_id, + token_symbol diff --git a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_token_hourly_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_token_hourly_base_mainnet.sql index 171eaaaa..4505ba94 100644 --- a/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_token_hourly_base_mainnet.sql +++ b/transformers/synthetix/models/marts/base/mainnet/core/fct_pool_rewards_token_hourly_base_mainnet.sql @@ -10,12 +10,12 @@ with dim as ( from ( select - min(ts_start) as min_ts, + min(r.ts_start) as min_ts, max( - ts_start + "duration" * '1 second'::INTERVAL + r.ts_start + r.duration * '1 second'::INTERVAL ) as max_ts from - {{ ref('fct_pool_rewards_base_mainnet') }} + {{ ref('fct_pool_rewards_base_mainnet') }} as r ) as t cross join ( select distinct @@ -38,7 +38,7 @@ rewards_distributed as ( token_symbol, amount, ts_start, - "duration" + duration from {{ ref('fct_pool_rewards_base_mainnet') }} ), @@ -52,7 +52,7 @@ hourly_distributions as ( r.token_symbol, r.amount, r.ts_start, - r."duration", + r.duration, row_number() over ( partition by dim.ts, @@ -73,9 +73,9 @@ hourly_distributions as ( r.collateral_type ) and dim.ts + '1 hour'::INTERVAL >= r.ts_start - and dim.ts < r.ts_start + r."duration" * '1 second'::INTERVAL + and dim.ts < r.ts_start + r.duration * '1 second'::INTERVAL where - r."duration" > 0 + r.duration > 0 ), streamed_rewards as ( @@ -88,27 +88,28 @@ streamed_rewards as ( -- get the amount of time distributed this hour -- use the smaller of those two intervals -- convert the interval to a number of hours - -- multiply the result by the hourly amount to get the amount distributed this hour + -- multiply the result by the hourly amount to + -- get the amount distributed this hour ( extract( epoch from least( - d."duration" / 3600 * '1 hour'::INTERVAL, + d.duration / 3600 * '1 hour'::INTERVAL, least( d.ts + '1 hour'::INTERVAL - greatest( d.ts, d.ts_start ), least( - d.ts_start + d."duration" * '1 second'::INTERVAL, + d.ts_start + d.duration * '1 second'::INTERVAL, d.ts + '1 hour'::INTERVAL ) - d.ts ) ) ) / 3600 ) * d.amount / ( - d."duration" / 3600 + d.duration / 3600 ) as amount from hourly_distributions as d @@ -130,7 +131,7 @@ instant_rewards as ( from rewards_distributed where - "duration" = 0 + duration = 0 ), combined as ( @@ -174,7 +175,6 @@ select ts, pool_id, collateral_type, - distributor, token_symbol, sum(amount) as amount, sum( @@ -186,5 +186,4 @@ group by ts, pool_id, collateral_type, - distributor, token_symbol diff --git a/transformers/synthetix/models/marts/base/mainnet/core/schema.yml b/transformers/synthetix/models/marts/base/mainnet/core/schema.yml index 57ad6b38..3f764d91 100644 --- a/transformers/synthetix/models/marts/base/mainnet/core/schema.yml +++ b/transformers/synthetix/models/marts/base/mainnet/core/schema.yml @@ -304,7 +304,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 @@ -562,7 +568,7 @@ models: data_type: numeric tests: - not_null - - name: fct_pool_rewards_hourly_base_mainnet + - name: fct_pool_rewards_pool_hourly_base_mainnet columns: - name: ts description: "Block timestamp" @@ -582,6 +588,19 @@ models: data_type: text tests: - not_null + - name: token_symbol + description: "Token symbol" + data_type: text + tests: + - not_null + - name: amount + description: "Distributed rewards amount" + data_type: numeric + tests: + - not_null + - dbt_utils.accepted_range: + min_value: 0 + inclusive: true - name: rewards_usd description: "Rewards value (USD)" data_type: numeric @@ -610,11 +629,6 @@ models: data_type: text tests: - not_null - - name: distributor - description: "Address of the distributor" - data_type: text - tests: - - not_null - name: token_symbol description: "Token symbol" data_type: text diff --git a/transformers/synthetix/models/marts/base/mainnet/prices/fct_prices_hourly_base_mainnet.sql b/transformers/synthetix/models/marts/base/mainnet/prices/fct_prices_hourly_base_mainnet.sql index 65829fe0..30656ebe 100644 --- a/transformers/synthetix/models/marts/base/mainnet/prices/fct_prices_hourly_base_mainnet.sql +++ b/transformers/synthetix/models/marts/base/mainnet/prices/fct_prices_hourly_base_mainnet.sql @@ -1,4 +1,9 @@ +{{ config( + materialized = 'table', +) }} + with prices as ( + select distinct market_symbol, DATE_TRUNC( @@ -43,10 +48,14 @@ ffill as ( select dim.ts, dim.market_symbol, - LAST(prices.price) over ( + LAST( + prices.price + ) over ( partition by dim.market_symbol - order by dim.ts - rows between unbounded preceding and current row + order by + dim.ts + rows between unbounded preceding + and current row ) as price from dim