Skip to content

Commit 4e270fd

Browse files
tokens.transfers_from_traces - fix nulls in value (#9024)
* fix & update & easy dates run * retrigger * revert easy dates * add metadata to final blockchain level macro * temp: use easy dates * add transfers start date param for efficient filtering * include new columns in final view * update all models to incremental tables * temp: update base easy dates to true * cosmetic: lowercase sql * cleanup new chain mezo to match other base models * add wrappers, add easy date usage, column aliases * cosmetic * Revert "cosmetic" This reverts commit 688777f. * cosmetic & visuality * revert easy dates --------- Co-authored-by: jeff-dude <[email protected]>
1 parent f29b977 commit 4e270fd

File tree

101 files changed

+580
-179
lines changed

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

101 files changed

+580
-179
lines changed

dbt_subprojects/tokens/macros/transfers_from_traces/transfers_from_traces_base_macro.sql

Lines changed: 23 additions & 17 deletions
Original file line numberDiff line numberDiff line change
@@ -1,15 +1,21 @@
1-
{%- macro transfers_from_traces_base_macro(blockchain, easy_dates=false) -%}
1+
{%- macro
2+
transfers_from_traces_base_macro(
3+
blockchain,
4+
easy_dates=false
5+
)
6+
-%}
27

38
-- this stream process all kind of transfers from traces: native, erc20 transfer/transferFrom, mint/burn, wrapped deposit/withdrawal
49

5-
{%- set null_address = '0x0000000000000000000000000000000000000000' -%}
6-
{%- set transfer_selector = '0xa9059cbb' -%}
7-
{%- set transferFrom_selector = '0x23b872dd' -%}
8-
{%- set mint_selector = '0x40c10f19' -%}{# for DAI, etc. #}
9-
{%- set burn_selector = '0x9dc29fac' -%}{# for DAI, etc. #}
10-
{%- set deposit_selector = '0xd0e30db0' -%}{# for wrappers #}
11-
{%- set withdraw_selector = '0x2e1a7d4d' -%}{# for wrappers #}
12-
{%- set selector = 'substr(input, 1, 4)' %}
10+
{%- set null_address = "0x0000000000000000000000000000000000000000" -%}
11+
{%- set transfer_selector = "0xa9059cbb" -%}
12+
{%- set transferFrom_selector = "0x23b872dd" -%}
13+
{%- set mint_selector = "0x40c10f19" -%}{# for DAI, etc. #}
14+
{%- set burn_selector = "0x9dc29fac" -%}{# for DAI, etc. #}
15+
{%- set deposit_selector = "0xd0e30db0" -%}{# for wrappers #}
16+
{%- set withdraw_selector = "0x2e1a7d4d" -%}{# for wrappers #}
17+
{%- set selector = "substr(input, 1, 4)" -%}
18+
{%- set value = "coalesce(value, uint256 '0')" %}
1319

1420
-- output --
1521

@@ -29,14 +35,14 @@ select
2935
when {{ selector }} = {{ deposit_selector }} then 'deposit'
3036
when {{ selector }} = {{ withdraw_selector }} then 'withdraw'
3137
else 'native'
32-
end as type
33-
, if(value > uint256 '0', 'native', 'erc20') as token_standard
34-
, if(value > uint256 '0', native_address, "to") as contract_address
38+
end as type
39+
, if({{ value }} > uint256 '0', 'native', 'erc20') as token_standard
40+
, if({{ value }} > uint256 '0', native_address, "to") as contract_address
3541
, case
3642
when {{ selector }} in ({{ transfer_selector }}, {{ mint_selector }}, {{ burn_selector }}) then bytearray_to_uint256(substr(input, 37, 32)) -- transfer, mint, burn
3743
when {{ selector }} = {{ transferFrom_selector }} then bytearray_to_uint256(substr(input, 69, 32)) -- transferFrom
3844
when {{ selector }} = {{ withdraw_selector }} then bytearray_to_uint256(substr(input, 5, 32)) -- withdraw
39-
else value -- native, deposit
45+
else {{ value }} -- native, deposit
4046
end as amount_raw
4147
, case
4248
when {{ selector }} in ({{ transferFrom_selector }}, {{ burn_selector }}) then substr(input, 17, 20) -- transferFrom, burn
@@ -56,21 +62,21 @@ select
5662
, cast(block_number as varchar)
5763
, cast(tx_hash as varchar)
5864
, array_join(trace_address, ',') -- ',' is necessary to avoid similarities after concatenation // array_join(array[1, 0], '') = array_join(array[10], '')
59-
, cast(if(value > uint256 '0', native_address, "to") as varchar)
65+
, cast(if({{ value }} > uint256 '0', native_address, "to") as varchar)
6066
))) as unique_key
6167
from {{ source(blockchain, 'traces') }}, (select token_address as native_address from {{ source('dune', 'blockchains') }} where name = '{{ blockchain }}') as meta
6268
where
6369
(
6470
length(input) >= 68 and {{ selector }} in ({{ transfer_selector }}, {{ mint_selector }}, {{ burn_selector }}) -- transfer, mint, burn
6571
or length(input) >= 100 and {{ selector }} = {{ transferFrom_selector }} -- transferFrom
6672
or length(input) >= 36 and {{ selector }} = {{ withdraw_selector }} -- withdraw
67-
or value > uint256 '0' -- native, deposit
73+
or {{ value }} > uint256 '0' -- native, deposit
6874
)
6975
and (call_type = 'call' or type = 'create') -- call_type should be only call if present; type = 'create' is contract creation
7076
and (tx_success or tx_success is null) -- tx_success is null - is for old ethereum data
7177
and success
72-
{% if easy_dates %}and block_date > current_date - interval '10' day{% endif %} -- easy_dates mode for dev, to prevent full scan
73-
{% if is_incremental() %}and {{ incremental_predicate('block_time') }}{% endif %}
78+
{% if easy_dates -%} and block_date > current_date - interval '10' day {%- endif %} -- easy_dates mode for dev, to prevent full scan
79+
{% if is_incremental() -%} and {{ incremental_predicate('block_time') }} {%- endif %}
7480

7581

7682

dbt_subprojects/tokens/macros/transfers_from_traces/transfers_from_traces_base_wrapper_deposits_macro.sql

Lines changed: 9 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,9 @@
1-
{%- macro transfers_from_traces_base_wrapper_deposits_macro(blockchain, transfers_from_traces_base_table) -%}
1+
{%- macro
2+
transfers_from_traces_base_wrapper_deposits_macro(
3+
blockchain,
4+
transfers_from_traces_base_table
5+
)
6+
-%}
27

38
-- the wrapper deposit includes two transfers: native and wrapped, so we should add second one manually reversing from/to
49
-- it's splitted to 2 operations and fetching from pre-materialized table to prevent doubling full-scan of traces
@@ -17,8 +22,8 @@ select
1722
, 'erc20' as token_standard
1823
, "to" as contract_address
1924
, amount_raw
20-
, "to" as transfer_from
21-
, "from" as transfer_to
25+
, "to"
26+
, "from"
2227
, sha1(to_utf8(concat_ws('|'
2328
, blockchain
2429
, cast(block_number as varchar)
@@ -34,7 +39,7 @@ join ( -- to leave only real tokens (mostly for wrapped token, but works for rar
3439
) using("to")
3540
where
3641
type = 'deposit'
37-
{% if is_incremental() %}and {{ incremental_predicate('block_time') }}{% endif %}
42+
{% if is_incremental() -%} and {{ incremental_predicate('block_time') }} {%- endif %}
3843

3944

4045

dbt_subprojects/tokens/macros/transfers_from_traces/transfers_from_traces_macro.sql

Lines changed: 117 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -1,12 +1,123 @@
1-
{%- macro transfers_from_traces_macro(blockchain) -%}
2-
-- it's splitted to 2 operations and fetching from pre-materialized table to prevent doubling full-scan of traces
1+
{%- macro
2+
transfers_from_traces_macro(
3+
blockchain,
4+
transfers_start_date='2000-01-01',
5+
easy_dates=false,
6+
prices_interval='hour'
7+
)
8+
-%}
39

10+
{%- if blockchain is none or blockchain == '' -%}
11+
{{- exceptions.raise_compiler_error("blockchain parameter cannot be null or empty") -}}
12+
{%- endif -%}
413

5-
select * from {{ ref('tokens_' ~ blockchain ~ '_transfers_from_traces_base') }}
614

7-
union all
8-
-- the wrapper deposit includes two transfers: native and wrapped, so need to add second one manually reversing from/to
9-
select * from {{ ref('tokens_' ~ blockchain ~ '_transfers_from_traces_base_wrapper_deposits') }}
15+
16+
with
17+
18+
base_tft as (
19+
select
20+
blockchain
21+
, block_month
22+
, block_date
23+
, block_time
24+
, block_number
25+
, tx_hash
26+
, trace_address
27+
, type
28+
, token_standard
29+
, contract_address
30+
, amount_raw
31+
, "from"
32+
, "to"
33+
, unique_key
34+
, date_trunc('{{ prices_interval }}', block_time) as timestamp
35+
from {{ ref('tokens_' ~ blockchain ~ '_transfers_from_traces_base') }}
36+
where true
37+
and block_date >= timestamp '{{ transfers_start_date }}'
38+
{% if easy_dates -%} and block_date > current_date - interval '10' day {%- endif %} -- easy_dates mode for dev, to prevent full scan
39+
{% if is_incremental() -%} and {{ incremental_predicate('block_date') }} {%- endif %}
40+
)
41+
42+
, base_tft_wrapper_deposits as (
43+
select
44+
blockchain
45+
, block_month
46+
, block_date
47+
, block_time
48+
, block_number
49+
, tx_hash
50+
, trace_address
51+
, type
52+
, token_standard
53+
, contract_address
54+
, amount_raw
55+
, "from"
56+
, "to"
57+
, unique_key
58+
, date_trunc('{{ prices_interval }}', block_time) as timestamp
59+
from {{ ref('tokens_' ~ blockchain ~ '_transfers_from_traces_base_wrapper_deposits') }}
60+
where true
61+
and block_date >= timestamp '{{ transfers_start_date }}'
62+
{% if easy_dates -%} and block_date > current_date - interval '10' day {%- endif %} -- easy_dates mode for dev, to prevent full scan
63+
{% if is_incremental() -%} and {{ incremental_predicate('block_date') }} {%- endif %}
64+
)
65+
66+
, tft as (
67+
select * from base_tft
68+
union all
69+
select * from base_tft_wrapper_deposits
70+
)
71+
72+
, tokens as (
73+
select
74+
contract_address
75+
, decimals as token_decimals
76+
, symbol as token_symbol
77+
from {{ source('tokens', 'erc20') }}
78+
where true
79+
and blockchain = '{{ blockchain }}'
80+
)
81+
82+
, prices as (
83+
select
84+
contract_address
85+
, timestamp
86+
, decimals
87+
, symbol
88+
, price
89+
from {{ source('prices_external', prices_interval) }}
90+
where true
91+
and blockchain = '{{ blockchain }}'
92+
and timestamp >= timestamp '{{ transfers_start_date }}'
93+
{% if easy_dates -%} and timestamp > current_date - interval '10' day {%- endif %} -- easy_dates mode for dev, to prevent full scan
94+
{% if is_incremental() -%} and {{ incremental_predicate('timestamp') }} {%- endif %}
95+
)
96+
97+
-- output --
98+
99+
select
100+
blockchain
101+
, block_month
102+
, block_date
103+
, block_time
104+
, block_number
105+
, tx_hash
106+
, trace_address
107+
, type
108+
, token_standard
109+
, contract_address
110+
, coalesce(token_symbol, symbol) as symbol
111+
, amount_raw
112+
, amount_raw / power(10, coalesce(token_decimals, decimals)) as amount
113+
, price as price_usd
114+
, amount_raw / power(10, coalesce(token_decimals, decimals)) * price as amount_usd
115+
, "from"
116+
, "to"
117+
, unique_key
118+
from tft
119+
left join tokens using(contract_address)
120+
left join prices using(contract_address, timestamp)
10121

11122

12123

dbt_subprojects/tokens/models/transfers_and_balances/abstract/tokens_abstract_transfers_from_traces.sql

Lines changed: 7 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4,8 +4,13 @@
44
config(
55
schema = 'tokens_' ~ blockchain,
66
alias = 'transfers_from_traces',
7-
materialized = 'view',
7+
partition_by = ['block_month'],
8+
materialized = 'incremental',
9+
file_format = 'delta',
10+
incremental_strategy = 'merge',
11+
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')],
12+
unique_key = ['block_date', 'unique_key'],
813
)
914
}}
1015

11-
{{ transfers_from_traces_macro(blockchain=blockchain) }}
16+
{{ transfers_from_traces_macro(blockchain=blockchain, transfers_start_date = '2024-10-30') }}

dbt_subprojects/tokens/models/transfers_and_balances/abstract/tokens_abstract_transfers_from_traces_base.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -13,4 +13,4 @@
1313
)
1414
}}
1515

16-
{{ transfers_from_traces_base_macro(blockchain=blockchain, easy_dates=false) }}
16+
{{ transfers_from_traces_base_macro(blockchain=blockchain) }}

dbt_subprojects/tokens/models/transfers_and_balances/apechain/tokens_apechain_transfers_from_traces.sql

Lines changed: 7 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4,8 +4,13 @@
44
config(
55
schema = 'tokens_' ~ blockchain,
66
alias = 'transfers_from_traces',
7-
materialized = 'view',
7+
partition_by = ['block_month'],
8+
materialized = 'incremental',
9+
file_format = 'delta',
10+
incremental_strategy = 'merge',
11+
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')],
12+
unique_key = ['block_date', 'unique_key'],
813
)
914
}}
1015

11-
{{ transfers_from_traces_macro(blockchain=blockchain) }}
16+
{{ transfers_from_traces_macro(blockchain=blockchain, transfers_start_date='2024-08-28') }}

dbt_subprojects/tokens/models/transfers_and_balances/apechain/tokens_apechain_transfers_from_traces_base.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -13,4 +13,4 @@
1313
)
1414
}}
1515

16-
{{ transfers_from_traces_base_macro(blockchain=blockchain, easy_dates=false) }}
16+
{{ transfers_from_traces_base_macro(blockchain=blockchain) }}

dbt_subprojects/tokens/models/transfers_and_balances/arbitrum/tokens_arbitrum_transfers_from_traces.sql

Lines changed: 7 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4,8 +4,13 @@
44
config(
55
schema = 'tokens_' ~ blockchain,
66
alias = 'transfers_from_traces',
7-
materialized = 'view',
7+
partition_by = ['block_month'],
8+
materialized = 'incremental',
9+
file_format = 'delta',
10+
incremental_strategy = 'merge',
11+
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')],
12+
unique_key = ['block_date', 'unique_key'],
813
)
914
}}
1015

11-
{{ transfers_from_traces_macro(blockchain=blockchain) }}
16+
{{ transfers_from_traces_macro(blockchain=blockchain, transfers_start_date='2021-05-29') }}

dbt_subprojects/tokens/models/transfers_and_balances/avalanche_c/tokens_avalanche_c_transfers_from_traces.sql

Lines changed: 7 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4,8 +4,13 @@
44
config(
55
schema = 'tokens_' ~ blockchain,
66
alias = 'transfers_from_traces',
7-
materialized = 'view',
7+
partition_by = ['block_month'],
8+
materialized = 'incremental',
9+
file_format = 'delta',
10+
incremental_strategy = 'merge',
11+
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')],
12+
unique_key = ['block_date', 'unique_key'],
813
)
914
}}
1015

11-
{{ transfers_from_traces_macro(blockchain=blockchain) }}
16+
{{ transfers_from_traces_macro(blockchain=blockchain, transfers_start_date='2020-09-23') }}

dbt_subprojects/tokens/models/transfers_and_balances/b3/tokens_b3_transfers_from_traces.sql

Lines changed: 7 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4,8 +4,13 @@
44
config(
55
schema = 'tokens_' ~ blockchain,
66
alias = 'transfers_from_traces',
7-
materialized = 'view',
7+
partition_by = ['block_month'],
8+
materialized = 'incremental',
9+
file_format = 'delta',
10+
incremental_strategy = 'merge',
11+
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')],
12+
unique_key = ['block_date', 'unique_key'],
813
)
914
}}
1015

11-
{{ transfers_from_traces_macro(blockchain=blockchain) }}
16+
{{ transfers_from_traces_macro(blockchain=blockchain, transfers_start_date='2024-07-31') }}

0 commit comments

Comments
 (0)