Skip to content

Commit

Permalink
Adding complete Lido data models (#405)
Browse files Browse the repository at this point in the history
  • Loading branch information
alexwes authored Aug 19, 2024
1 parent 4283e40 commit edfadf9
Show file tree
Hide file tree
Showing 9 changed files with 602 additions and 25 deletions.
139 changes: 139 additions & 0 deletions macros/get_treasury_balance.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,139 @@
{% macro get_treasury_balance(chain, addresses)%}

WITH dates AS (
SELECT
DISTINCT DATE(hour) AS date
FROM
{{ chain }}_flipside.price.ez_prices_hourly
WHERE
symbol = 'UNI'
),
tokens AS (
SELECT
DISTINCT LOWER(contract_address) AS token_address
FROM
{{ chain }}_flipside.core.ez_token_transfers
WHERE
{% if addresses is string %} LOWER(to_address) = '{{ addresses }}'
{% elif addresses | length > 1 %} LOWER(to_address) in {{addresses}}
{% endif %}
),
sparse_balances AS (
SELECT
DATE(block_timestamp) AS date,
user_address,
contract_address,
MAX_BY(balance, block_timestamp) / 1e18 AS balance_daily
FROM
{{ chain }}_flipside.core.fact_token_balances
WHERE
LOWER(contract_address) IN (
SELECT
token_address
FROM
tokens
)
AND
{% if addresses is string %} LOWER(user_address) = '{{ addresses }}'
{% elif addresses | length > 1 %} LOWER(user_address) in {{addresses}}
{% endif %}
GROUP BY
1,
2,
3
),
full_balances AS (
SELECT
d.date,
{% if addresses is string %}
'{{ addresses }}' AS user_address,
{% else %}
ta.address AS user_address,
{% endif %}
t.token_address AS contract_address,
COALESCE(
LAST_VALUE(sb.balance_daily) IGNORE NULLS OVER (
PARTITION BY
{% if addresses is string %}
'{{ addresses }}'
{% else %}
ta.address
{% endif %},
t.token_address
ORDER BY
d.date ROWS BETWEEN UNBOUNDED PRECEDING
AND CURRENT ROW
),
0
) AS balance_daily
FROM
dates d
{% if addresses is string %}
CROSS JOIN (SELECT '{{ addresses }}' AS address) ta
{% else %}
CROSS JOIN (SELECT unnest({{ addresses }}) AS address) ta
{% endif %}
CROSS JOIN tokens t
LEFT JOIN sparse_balances sb ON d.date = sb.date
AND
{% if addresses is string %}
'{{ addresses }}' = sb.user_address
{% else %}
ta.address = sb.user_address
{% endif %}
AND t.token_address = sb.contract_address
),
daily_prices AS (
SELECT
DATE(hour) AS date,
token_address,
symbol,
AVG(price) AS avg_daily_price,
MAX(decimals) as decimals
FROM
{{ chain }}_flipside.price.ez_prices_hourly
WHERE
token_address IN (
SELECT
token_address
FROM
tokens
)
GROUP BY
1,
2,
3
),
full_table as (
SELECT
fb.date,
fb.user_address,
fb.contract_address,
dp.symbol,
fb.balance_daily as balance_daily,
COALESCE(dp.avg_daily_price, 0) AS avg_daily_price,
fb.balance_daily * COALESCE(dp.avg_daily_price, 0) AS usd_balance
FROM
full_balances fb
LEFT JOIN daily_prices dp ON fb.date = dp.date
AND fb.contract_address = dp.token_address -- AND dp.decimals is not null
-- and dp.decimals > 0
WHERE
symbol is not null
)
SELECT
date,
symbol as token,
SUM(balance_daily) as native_balance,
SUM(usd_balance) as usd_balance
FROM
full_table
WHERE
USD_BALANCE > 1
GROUP BY
1
, 2
ORDER BY
1 DESC

{% endmacro %}
22 changes: 14 additions & 8 deletions macros/metrics/get_coingecko_metrics.sql
Original file line number Diff line number Diff line change
@@ -1,9 +1,12 @@
{% macro get_coingecko_metrics(coingecko_id) %}
select
date as date,
shifted_token_price_usd as price,
shifted_token_market_cap as market_cap,
t2.total_supply * price as fdmc
date as date
, shifted_token_price_usd as price
, shifted_token_market_cap as market_cap
, t2.total_supply * price as fdmc
, shifted_token_h24_volume_usd / market_cap as token_turnover_circulating
, shifted_token_h24_volume_usd / fdmc as token_turnover_fdv
, shifted_token_h24_volume_usd as token_volume
from {{ ref("fact_coingecko_token_date_adjusted_gold") }} t1
inner join
(
Expand All @@ -18,10 +21,13 @@
and date < dateadd(day, -1, to_date(sysdate()))
union
select
dateadd('day', -1, to_date(sysdate())) as date,
token_current_price as price,
token_market_cap as market_cap,
coalesce(token_max_supply, token_total_supply) * price as fdmc
dateadd('day', -1, to_date(sysdate())) as date
, token_current_price as price
, token_market_cap as market_cap
, coalesce(token_max_supply, token_total_supply) * price as fdmc
, token_total_volume / market_cap as token_turnover_circulating
, token_total_volume / fdmc as token_turnover_fdv
, token_total_volume as token_volume
from {{ ref("fact_coingecko_token_realtime_data") }}
where token_id = '{{ coingecko_id }}'
{% endmacro %}
109 changes: 109 additions & 0 deletions models/projects/lido/core/ez_lido_metrics.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,109 @@
{{
config(
materialized="table",
snowflake_warehouse="LIDO",
database="lido",
schema="core",
alias="ez_metrics",
)
}}

with
fees_revenue_expenses as (
SELECT
date
, block_rewards
, mev_priority_fees
, total_staking_yield as fees
, operating_expenses
, protocol_revenue
, primary_supply_side_revenue
, secondary_supply_side_revenue
, total_supply_side_revenue
FROM {{ ref('fact_lido_fees_revs_expenses') }}
)
, staked_eth_metrics as (
select
date
, num_staked_eth
, amount_staked_usd
from {{ ref('fact_lido_staked_eth_count_with_USD_and_change') }}
)
, treasury_cte as (
SELECT
date
, sum(usd_balance) as treasury_value
FROM
{{ ref('fact_lido_dao_treasury') }}
GROUP BY 1
)
, treasury_native_cte as (
SELECT
date
, sum(native_balance) as treasury_native
FROM
{{ ref('fact_lido_dao_treasury') }}
where token = 'LDO'
GROUP BY 1
)
, net_treasury_cte as (
SELECT
date
, sum(usd_balance) as net_treasury_value
FROM {{ ref('fact_lido_dao_treasury') }}
where token <> 'LDO'
group by 1
)
, token_incentives_cte as (
SELECT
date
, sum(amount_usd) as token_incentives
FROM
{{ ref('fact_lido_token_incentives') }}
GROUP BY 1
)
, price_data as (
{{ get_coingecko_metrics('lido-dao') }}
)
, tokenholder_cte as (
SELECT
date,
token_holder_count
FROM
{{ ref('fact_ldo_tokenholder_count')}}
)
select
s.date
, COALESCE(f.mev_priority_fees, 0) as mev_priority_fees
, COALESCE(f.block_rewards, 0) as block_rewards
, COALESCE(f.fees, 0) as fees
, COALESCE(f.primary_supply_side_revenue, 0) as primary_supply_side_revenue
, COALESCE(f.secondary_supply_side_revenue, 0) as secondary_supply_side_revenue
, COALESCE(f.total_supply_side_revenue, 0) as total_supply_side_revenue
, COALESCE(f.protocol_revenue, 0) as protocol_revenue
, COALESCE(f.operating_expenses, 0) as operating_expenses
, COALESCE(ti.token_incentives, 0) as token_incentives
, COALESCE(f.protocol_revenue, 0) - COALESCE(f.operating_expenses, 0) - COALESCE(ti.token_incentives, 0) as protocol_earnings
, COALESCE(t.treasury_value, 0) as treasury_value
, COALESCE(tn.treasury_native, 0) as treasury_native
, COALESCE(nt.net_treasury_value, 0) as net_treasury_value
, COALESCE(s.amount_staked_usd, 0) as net_deposits
, COALESCE(s.num_staked_eth, 0) as outstanding_supply
, COALESCE(s.amount_staked_usd, 0) as tvl
, COALESCE(s.amount_staked_usd, 0) as amount_staked_usd
, COALESCE(s.num_staked_eth, 0) as num_staked_eth
, COALESCE(p.fdmc, 0) as fdmc
, COALESCE(p.market_cap, 0) as market_cap
, COALESCE(p.token_volume, 0) as token_volume
, COALESCE(p.token_turnover_fdv, 0) as token_turnover_fdv
, COALESCE(p.token_turnover_circulating, 0) as token_turnover_circulating
, COALESCE(th.token_holder_count, 0) as token_holder_count
from staked_eth_metrics s
left join fees_revenue_expenses f using(date)
left join treasury_cte t using(date)
left join treasury_native_cte tn using(date)
left join net_treasury_cte nt using(date)
left join token_incentives_cte ti using(date)
left join price_data p using(date)
left join tokenholder_cte th using(date)
where s.date < current_date()
Loading

0 comments on commit edfadf9

Please sign in to comment.