-
Notifications
You must be signed in to change notification settings - Fork 1.1k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
1 parent
0f1b482
commit 374150e
Showing
1 changed file
with
95 additions
and
0 deletions.
There are no files selected for viewing
95 changes: 95 additions & 0 deletions
95
dbt_subprojects/hourly_spellbook/models/_project/safe/polygon/safe_polygon_balances.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,95 @@ | ||
{{ | ||
config( | ||
schema = 'safe_polygon', | ||
alias = 'balances', | ||
partition_by = ['day'], | ||
materialized = 'incremental', | ||
incremental_strategy = 'merge', | ||
file_format = 'delta', | ||
unique_key = ['day', 'blockchain', 'address', 'token_address'], | ||
post_hook = '{{ expose_spells(\'["polygon"]\', | ||
"project", | ||
"safe", | ||
\'["safeintern"]\') }}' | ||
) | ||
}} | ||
|
||
with changed_balances as ( | ||
select | ||
a.blockchain, | ||
day, | ||
a.address, | ||
token_symbol, | ||
token_address, | ||
token_standard, | ||
token_id, | ||
balance, | ||
lead(cast(day as timestamp)) over (partition by token_address, a.address, token_id order by day asc) as next_update_day | ||
from {{ source('tokens_polygon', 'balances_daily_agg') }} a | ||
join ( | ||
select | ||
address | ||
, blockchain | ||
from {{ ref('safe_polygon_safes') }} s | ||
where blockchain = 'polygon' | ||
) q on q.address = a.address | ||
where day >= date('2021-07-01') | ||
and token_standard in ('native', 'erc20') | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('day') }} | ||
{% endif %} | ||
), | ||
days as ( | ||
select * | ||
from unnest( | ||
sequence(cast('2021-07-01' as date), date(date_trunc('day', now())), interval '1' day) | ||
) as foo(day) | ||
), | ||
forward_fill as ( | ||
select | ||
blockchain, | ||
cast(d.day as date) as day, | ||
address, | ||
token_symbol, | ||
token_address, | ||
token_standard, | ||
token_id, | ||
balance | ||
from days d | ||
left join changed_balances b | ||
on d.day >= b.day | ||
and (b.next_update_day is null OR d.day < b.next_update_day) | ||
where d.day >= cast('2021-07-01' as date) | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('d.day') }} | ||
{% endif %} | ||
) | ||
select | ||
b.day, | ||
b.blockchain, | ||
b.address, | ||
b.token_address, | ||
b.token_standard, | ||
b.token_id, | ||
b.token_symbol, | ||
sum(b.balance) as token_balance, | ||
sum(b.balance * p.price) as balance_usd | ||
from ( | ||
select * from forward_fill | ||
where balance > 0 | ||
) b | ||
left join {{ ref('prices_usd_daily') }} p | ||
on ( | ||
token_standard = 'erc20' | ||
and b.blockchain = p.blockchain | ||
and b.token_address = p.contract_address | ||
and b.day = p.day | ||
) | ||
or ( | ||
token_standard = 'native' | ||
and p.blockchain is null | ||
and p.contract_address is null | ||
and p.symbol = 'ETH' | ||
and b.day = p.day | ||
) | ||
group by 1, 2, 3, 4, 5, 6, 7 |