-
Notifications
You must be signed in to change notification settings - Fork 1.2k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
* adds celo to transfers * added missing dunesql tag * amended transfers_celo_erc20, added test * tweaked varchar size * replaced legacy transfers with placeholder * added block_month, left amount_raw as double * too many commas.. * Remove file format * Revert "Remove file format" This reverts commit d511239. * updated unique_key * amended schema * column name tweak * more tweaks to test file * added amount_raw to unique_key * test with limited data sample * back to full dataset (except for WCELO) * join tweak and 1mln limit test * limit 100k test.. * and 1k limit test.. * cast block_month as date * tidying up * applying suggested changes * updated schema * updated test total * Add uniqueness test --------- Co-authored-by: Huang Geyang <Sukebeta@outlook.com>
- Loading branch information
Showing
7 changed files
with
329 additions
and
0 deletions.
There are no files selected for viewing
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
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,109 @@ | ||
{{ | ||
config( | ||
tags = ['dunesql'], | ||
alias = alias('erc20'), | ||
partition_by = ['block_month'], | ||
materialized = 'incremental', | ||
file_format = 'delta', | ||
incremental_strategy = 'merge', | ||
unique_key = ['tx_hash', 'type', 'evt_index', 'wallet_address'], | ||
post_hook='{{ expose_spells(\'["celo"]\', | ||
"sector", | ||
"transfers", | ||
\'["soispoke", "dot2dotseurat", "tschubotz", "tomfutago"]\') }}' | ||
) | ||
}} | ||
|
||
with | ||
sent_transfers as ( | ||
select | ||
'sent' as type, | ||
to as wallet_address, | ||
contract_address as token_address, | ||
evt_block_time as block_time, | ||
cast(date_trunc('month', evt_block_time) as date) as block_month, | ||
cast(value as double) as amount_raw, | ||
evt_index, | ||
evt_tx_hash as tx_hash | ||
from | ||
{{ source('erc20_celo', 'evt_transfer') }} | ||
where 1=1 | ||
{% if is_incremental() %} -- this filter will only be applied on an incremental run | ||
and evt_block_time >= date_trunc('day', now() - interval '7' day) | ||
{% endif %} | ||
), | ||
|
||
received_transfers as ( | ||
select | ||
'received' as type, | ||
"from" as wallet_address, | ||
contract_address as token_address, | ||
evt_block_time as block_time, | ||
cast(date_trunc('month', evt_block_time) as date) as block_month, | ||
(-1) * cast(value as double) as amount_raw, | ||
evt_index, | ||
evt_tx_hash as tx_hash | ||
from | ||
{{ source('erc20_celo', 'evt_transfer') }} | ||
where 1=1 | ||
{% if is_incremental() %} -- this filter will only be applied on an incremental run | ||
and evt_block_time >= date_trunc('day', now() - interval '7' day) | ||
{% endif %} | ||
|
||
) | ||
|
||
/*, | ||
-- Wrapped Celo looks to work differently than WETH - commenting this section out for now | ||
deposited_wcelo as ( | ||
select | ||
bytearray_substring(topic1,13,20) as wallet_address, | ||
contract_address as token_address, | ||
block_time, | ||
date_trunc('month', block_time) as block_month, | ||
cast(bytearray_to_uint256(data) as double) as amount_raw, | ||
index, | ||
tx_hash | ||
from | ||
{{ source('celo', 'logs') }} | ||
where contract_address = 0x3Ad443d769A07f287806874F8E5405cE3Ac902b9 --Wrapped Celo | ||
and topic0 = 0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef --deposit | ||
and bytearray_substring(topic1,13,20) <> 0x0000000000000000000000000000000000000000 | ||
{% if is_incremental() %} -- this filter will only be applied on an incremental run | ||
and block_time >= date_trunc('day', now() - interval '7' day) | ||
{% endif %} | ||
), | ||
withdrawn_wcelo as ( | ||
select | ||
bytearray_substring(topic1,13,20) as wallet_address, | ||
contract_address as token_address, | ||
block_time, | ||
date_trunc('month', block_time) as block_month, | ||
(-1) * cast(bytearray_to_uint256(data) as double) as amount_raw, | ||
index, | ||
tx_hash | ||
from | ||
{{ source('celo', 'logs') }} | ||
where contract_address = 0x3Ad443d769A07f287806874F8E5405cE3Ac902b9 --Wrapped Celo | ||
and topic0 = 0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef --withdrawal | ||
and bytearray_substring(topic1,13,20) = 0x0000000000000000000000000000000000000000 | ||
{% if is_incremental() %} -- this filter will only be applied on an incremental run | ||
and block_time >= date_trunc('day', now() - interval '7' day) | ||
{% endif %} | ||
) | ||
*/ | ||
|
||
select 'celo' as blockchain, type, wallet_address, token_address, block_time, block_month, amount_raw, evt_index, tx_hash | ||
from sent_transfers | ||
union | ||
select 'celo' as blockchain, type, wallet_address, token_address, block_time, block_month, amount_raw, evt_index, tx_hash | ||
from received_transfers | ||
|
||
/* | ||
union | ||
select 'celo' as blockchain, wallet_address, token_address, block_time, block_month, amount_raw, index, tx_hash | ||
from deposited_wcelo | ||
union | ||
select 'celo' as blockchain, wallet_address, token_address, block_time, block_month, amount_raw, index, tx_hash | ||
from withdrawn_wcelo | ||
*/ |
13 changes: 13 additions & 0 deletions
13
models/transfers/celo/erc20/transfers_celo_erc20_legacy.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,13 @@ | ||
{{ config( | ||
tags=['legacy'], | ||
schema = 'transfers_celo', | ||
alias = alias('erc20', legacy_model=True), | ||
) }} | ||
|
||
select | ||
'1' as unique_transfer_id, | ||
'celo' as blockchain, | ||
'0x' as wallet_address, | ||
'0x' as token_address, | ||
timestamp '2023-01-01' as evt_block_time, | ||
'1' as amount_raw |
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,79 @@ | ||
{{ | ||
config( | ||
tags = ['dunesql'], | ||
alias = alias('celo'), | ||
partition_by = ['block_month'], | ||
materialized = 'incremental', | ||
file_format = 'delta', | ||
incremental_strategy = 'merge', | ||
unique_key = ['tx_hash', 'trace_address'], | ||
post_hook='{{ expose_spells(\'["celo"]\', | ||
"sector", | ||
"transfers", | ||
\'["msilb7", "chuxin", "tomfutago"]\') }}' | ||
) | ||
}} | ||
|
||
with celo_transfers as ( | ||
select | ||
r."from" | ||
,r.to | ||
--Using the CELO deposit placeholder address to match with prices tables | ||
,0xDeadDeAddeAddEAddeadDEaDDEAdDeaDDeAD0000 as contract_address | ||
,cast(r.value as double) AS value | ||
,cast(r.value as double)/1e18 as value_decimal | ||
,r.tx_hash | ||
,r.trace_address | ||
,cast(date_trunc('month', r.block_time) as date) as block_month | ||
,r.block_time as tx_block_time | ||
,r.block_number as tx_block_number | ||
,substring(to_hex(t.data), 1, 10) as tx_method_id | ||
,t.to as tx_to | ||
,t."from" as tx_from | ||
from {{ source('celo', 'traces') }} as r | ||
join {{ source('celo', 'transactions') }} as t | ||
on r.tx_hash = t.hash | ||
and r.block_time = t.block_time | ||
where | ||
(r.call_type not in ('delegatecall', 'callcode', 'staticcall') or r.call_type is null) | ||
and r.tx_success | ||
and r.success | ||
and r.value > uint256 '0' | ||
{% if is_incremental() %} -- this filter will only be applied on an incremental run | ||
and r.block_time >= date_trunc('day', now() - interval '7' day) | ||
and t.block_time >= date_trunc('day', now() - interval '7' day) | ||
{% endif %} | ||
|
||
union all | ||
--CELO Transfers from deposits and withdrawals are ERC20 transfers of the 'deadeadead' CELO token. These do not appear in traces. | ||
|
||
select | ||
r."from" | ||
,r.to | ||
--Using the CELO deposit placeholder address to match with prices tables | ||
,0xDeadDeAddeAddEAddeadDEaDDEAdDeaDDeAD0000 as contract_address | ||
,cast(r.value as double) AS value | ||
,cast(r.value as double)/1e18 as value_decimal | ||
,r.evt_tx_hash as tx_hash | ||
,array[r.evt_index] as trace_address | ||
,cast(date_trunc('month', r.evt_block_time) as date) as block_month | ||
,r.evt_block_time as tx_block_time | ||
,r.evt_block_number as tx_block_number | ||
,substring(to_hex(t.data), 1, 10) as tx_method_id | ||
,t.to AS tx_to | ||
,t."from" AS tx_from | ||
from {{ source('erc20_celo', 'evt_transfer') }} as r | ||
join {{ source('celo', 'transactions') }} as t | ||
on r.evt_tx_hash = t.hash | ||
and r.evt_block_time = t.block_time | ||
where | ||
r.contract_address = 0xDeadDeAddeAddEAddeadDEaDDEAdDeaDDeAD0000 | ||
and t.success | ||
and r.value > uint256 '0' | ||
{% if is_incremental() %} -- this filter will only be applied on an incremental run | ||
and r.evt_block_time >= date_trunc('day', now() - interval '7' day) | ||
and t.block_time >= date_trunc('day', now() - interval '7' day) | ||
{% endif %} | ||
) | ||
select * | ||
from celo_transfers |
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,11 @@ | ||
{{ | ||
config( | ||
tags=['legacy'], | ||
schema = 'transfers_celo', | ||
alias = alias('celo', legacy_model=True) | ||
) | ||
}} | ||
|
||
-- DUMMY TABLE, WILL BE REMOVED SOON | ||
select | ||
1 |
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,100 @@ | ||
version: 2 | ||
|
||
models: | ||
- name: transfers_celo_celo | ||
meta: | ||
blockchain: celo | ||
sector: transfers | ||
project: celo | ||
contributors: msilb7, chuxin, tomfutago | ||
config: | ||
tags: ["transfers", "celo"] | ||
description: "Events of native CELO transfers on Celo." | ||
tests: | ||
- dbt_utils.unique_combination_of_columns: | ||
combination_of_columns: | ||
- tx_hash | ||
- trace_address | ||
columns: | ||
- &from | ||
name: from | ||
description: "Wallet address that initiated the transaction" | ||
- &to | ||
name: to | ||
description: "Wallet address that received the transaction" | ||
- name: contract_address | ||
description: "Using the CELO deposit placeholder address to match with prices tables" | ||
- &value | ||
name: value | ||
description: "Amount of CELO transferred from sender to recipient" | ||
- &value_decimal | ||
name: value_decimal | ||
description: "Amount of CELO transferred in decimals from sender to recipient" | ||
- &tx_hash | ||
name: tx_hash | ||
description: "Primary key of the transaction" | ||
tests: | ||
- not_null | ||
- name: trace_address | ||
description: "All returned traces, gives the exact location in the call trace" | ||
- &block_month | ||
name: block_month | ||
description: "Block Month column used to partition data in this table" | ||
tests: | ||
- not_null | ||
- &tx_block_time | ||
name: tx_block_time | ||
description: "Timestamp for block event time in UTC" | ||
- &tx_block_number | ||
name: tx_block_number | ||
description: "Block number" | ||
- &tx_method_id | ||
name: tx_method_id | ||
description: "Function calls specified by the first four bytes of data sent with a transaction" | ||
- &tx_to | ||
name: tx_to | ||
description: "To Address for the Transaction" | ||
- &tx_from | ||
name: tx_from | ||
description: "From Address for the Transaction" | ||
|
||
- name: transfers_celo_erc20 | ||
meta: | ||
blockchain: celo | ||
sector: transfers | ||
project: erc20 | ||
contributors: soispoke, dot2dotseurat, tschubotz, tomfutago | ||
config: | ||
tags: ['transfers', 'celo', 'erc20'] | ||
description: "ERC20 Token Transfers on Celo. This table is updated every 30 minutes." | ||
tests: | ||
- dbt_utils.unique_combination_of_columns: | ||
combination_of_columns: | ||
- tx_hash | ||
- type | ||
- evt_index | ||
- wallet_address | ||
columns: | ||
- &blockchain | ||
name: blockchain | ||
description: "Blockchain" | ||
- &type | ||
name: type | ||
description: "Transfer Type: sent/received" | ||
- &wallet_address | ||
name: wallet_address | ||
description: "Wallet address of sender or receiver. If amount is negative, wallet address is the sender's." | ||
- &token_address | ||
name: token_address | ||
description: "Contract address for token" | ||
- &block_time | ||
name: block_time | ||
description: "Timestamp for block event time in UTC" | ||
- *block_month | ||
- &amount_raw | ||
name: amount_raw | ||
description: "Raw amount of ERC20 token held *before* taking into account token decimals" | ||
- &evt_index | ||
name: evt_index | ||
description: "Event Index" | ||
- *tx_hash |
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,15 @@ | ||
-- Check that number of transfers in data range is correct | ||
with test_data as ( | ||
select count(*) as total | ||
from {{ ref('transfers_celo_erc20') }} | ||
where date(block_time) between date('2023-01-01') and date('2023-02-01') | ||
), | ||
|
||
test_result as ( | ||
select case when total = 31091176 then true else false end as success | ||
from test_data | ||
) | ||
|
||
select * | ||
from test_result | ||
where success = false |