Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: add chainswap #6332

Closed
wants to merge 22 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
143 changes: 143 additions & 0 deletions models/chain_swap/arbitrum/chain_swap_arbitrum_trades.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,143 @@
{{
config(
alias='trades',
schema='chain_swap_arbitrum',
partition_by=['block_month'],
materialized='incremental',
file_format='delta',
incremental_strategy='merge',
incremental_predicates=[
incremental_predicate('DBT_INTERNAL_DEST.block_time')
],
unique_key=['blockchain', 'tx_hash', 'evt_index'],
)
}}

{% set project_start_date = '2024-03-19' %}
{% set blockchain = 'arbitrum' %}
{% set deployer_1 = '0x9eC1ACAe39d07E1e8D8B3cEbe7022790D87D744A' %}
{% set deployer_2 = '0x415EEc63c95e944D544b3088bc682B759edB8548' %}
{% set deployer_3 = '0xc1cc1a300Dcfe5359eBe37f2007A77d1F91533ba' %}
{% set deployer_4 = '0x3A510C5a32bCb381c53704AED9c02b0c70041F7A' %}
{% set deployer_5 = '0xb7b953e81612c57256ff0aebd62b6a2f0546f7da' %}
{% set weth_contract_address = '0x82aF49447D8a07e3bd95BD0d56f35241523fBab1' %}
{% set usdc_contract_address = '0xaf88d065e77c8cC2239327C5EDb3A432268e5831' %}
{% set fee_recipient_1 = '0x415EEc63c95e944D544b3088bc682B759edB8548' %}
{% set fee_recipient_2 = '0xe1ff5a4c489b11e094bfbb5d23c6d4597a3a79ad' %}

with
bot_contracts as (
select address
from {{ source('arbitrum', 'creation_traces') }}
where
(
"from" = {{ deployer_1 }}
or "from" = {{ deployer_2 }}
or "from" = {{ deployer_3 }}
or "from" = {{ deployer_4 }}
or "from" = {{ deployer_5 }}
)
and block_time >= timestamp '{{project_start_date}}'

Comment on lines +40 to +41
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Maybe we can add an incremental filter here.

),
bot_trades as (
select
trades.block_time,
amount_usd,
if(token_sold_address = {{ weth_contract_address }}, 'Buy', 'Sell') as type,
token_bought_amount,
token_bought_symbol,
token_bought_address,
token_sold_amount,
token_sold_symbol,
token_sold_address,
project,
version,
token_pair,
project_contract_address,
tx_from as user,
tx_to as bot,
trades.tx_hash,
evt_index
from {{ source('dex', 'trades') }} as trades
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We can apply incremental filters to most selection from large tables/sources.

join bot_contracts on trades.tx_to = bot_contracts.address
where
trades.blockchain = '{{blockchain}}'
and trades.block_time >= timestamp '{{project_start_date}}'
and (tx_from != {{ fee_recipient_1 }} and tx_from != {{ fee_recipient_2 }})
order by trades.block_time desc, trades.evt_index desc
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Since this is not the final select, I am not sure if the order by works here.

),
highest_event_index_for_each_trade as (
select tx_hash, max(evt_index) as highest_event_index
from bot_trades
group by tx_hash
),
fee_deposits as (
select
evt_tx_hash,
value as fee_token_amount,
contract_address as fee_token_address
from {{ source('erc20_arbitrum', 'evt_transfer') }}
where
(to = {{ fee_recipient_1 }} or to = {{ fee_recipient_2 }})
and evt_block_time >= timestamp '{{project_start_date}}'
and value > 0
and (
contract_address = {{ weth_contract_address }}
or contract_address = {{ usdc_contract_address }}
)
union all
select
tx_hash,
value as fee_token_amount,
{{ weth_contract_address }} as fee_token_address
from {{ source('arbitrum', 'traces') }}
where
(to = {{ fee_recipient_1 }} or to = {{ fee_recipient_2 }})
and block_time >= timestamp '{{project_start_date}}'
and value > 0

)
select distinct
block_time,
date_trunc('day', block_time) as block_date,
date_trunc('month', block_time) as block_month,
'{{blockchain}}' as blockchain,
-- Trade
amount_usd,
type,
token_bought_amount,
token_bought_symbol,
cast(token_bought_address as varchar) as token_bought_address,
token_sold_amount,
token_sold_symbol,
cast(token_sold_address as varchar) as token_sold_address,
-- Fees
fee_token_amount / power(10, decimals) * price as fee_usd,
fee_token_amount / power(10, decimals) as fee_token_amount,
symbol as fee_token_symbol,
cast(fee_token_address as varchar) as fee_token_address,
-- Dex
project,
version,
token_pair,
cast(project_contract_address as varchar) as project_contract_address,
-- User
cast(user as varchar) as user,
cast(bot_trades.tx_hash as varchar) as tx_hash,
evt_index,
if(evt_index = highest_event_index, true, false) as is_last_trade_in_transaction
from bot_trades
join
highest_event_index_for_each_trade
on bot_trades.tx_hash = highest_event_index_for_each_trade.tx_hash
/* Left Outer Join to support 0 fee trades */
left join fee_deposits on bot_trades.tx_hash = fee_deposits.evt_tx_hash
left join
{{ source('prices', 'usd') }}
on (
blockchain = '{{blockchain}}'
and contract_address = fee_token_address
and minute = date_trunc('minute', block_time)
)
order by block_time desc, evt_index desc
150 changes: 150 additions & 0 deletions models/chain_swap/avalanche_c/chain_swap_avalanche_c_trades.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,150 @@
{{
config(
alias='trades',
schema='chain_swap_avalanche_c',
partition_by=['block_month'],
materialized='incremental',
file_format='delta',
incremental_strategy='merge',
incremental_predicates=[
incremental_predicate('DBT_INTERNAL_DEST.block_time')
],
unique_key=['blockchain', 'tx_hash', 'evt_index'],
)
}}

{% set project_start_date = '2024-03-28' %}
{% set blockchain = 'avalanche_c' %}
{% set deployer_1 = '0x9eC1ACAe39d07E1e8D8B3cEbe7022790D87D744A' %}
{% set deployer_2 = '0x415EEc63c95e944D544b3088bc682B759edB8548' %}
{% set deployer_3 = '0xc1cc1a300Dcfe5359eBe37f2007A77d1F91533ba' %}
{% set deployer_4 = '0xa24e8cE77D4A7Ce869DA3730e6560BfB66553F94' %}
{% set wavax_contract_address = '0xB31f66AA3C1e785363F0875A1B74E27b85FD66c7' %}
{% set usdc_contract_address = '0xB97EF9Ef8734C71904D8002F8b6Bc66Dd9c48a6E' %}
{% set fee_recipient_1 = '0x415EEc63c95e944D544b3088bc682B759edB8548' %}
{% set fee_recipient_2 = '0xe1ff5a4c489b11e094bfbb5d23c6d4597a3a79ad' %}

with
bot_contracts as (
select address
from {{ source('avalanche_c', 'creation_traces') }}
where
(
"from" = {{ deployer_1 }}
or "from" = {{ deployer_2 }}
or "from" = {{ deployer_3 }}
or "from" = {{ deployer_4 }}
)
and block_time >= timestamp '{{project_start_date}}'
),
bot_trades as (
select
trades.block_time,
amount_usd,
if(token_sold_address = {{ wavax_contract_address }}, 'Buy', 'Sell') as type,
token_bought_amount,
token_bought_symbol,
token_bought_address,
token_sold_amount,
token_sold_symbol,
token_sold_address,
project,
version,
token_pair,
project_contract_address,
tx_from as user,
tx_to as bot,
trades.tx_hash,
evt_index
from {{ source('dex', 'trades') }} as trades
join bot_contracts on trades.tx_to = bot_contracts.address
where
trades.blockchain = '{{blockchain}}'
and (tx_from != {{ fee_recipient_1 }} and tx_from != {{ fee_recipient_2 }})
{% if is_incremental() %}
and {{ incremental_predicate('trades.block_time') }}
{% else %}
and trades.block_time >= timestamp '{{project_start_date}}'
{% endif %}
),
highest_event_index_for_each_trade as (
select tx_hash, max(evt_index) as highest_event_index
from bot_trades
group by tx_hash
),
fee_deposits as (
select
evt_tx_hash,
value as fee_token_amount,
contract_address as fee_token_address
from {{ source('erc20_avalanche_c', 'evt_transfer') }}
where
(to = {{ fee_recipient_1 }} or to = {{ fee_recipient_2 }})
and value > 0
and (
contract_address = {{ wavax_contract_address }}
or contract_address = {{ usdc_contract_address }}
)
{% if is_incremental() %}
and {{ incremental_predicate('evt_block_time') }}
{% else %}
and evt_block_time >= timestamp '{{project_start_date}}'
{% endif %}
union all
select
tx_hash,
value as fee_token_amount,
{{ wavax_contract_address }} as fee_token_address
from {{ source('avalanche_c', 'traces') }}
where
(to = {{ fee_recipient_1 }} or to = {{ fee_recipient_2 }})
and value > 0
{% if is_incremental() %}
and {{ incremental_predicate('block_time') }}
{% else %}
and block_time >= timestamp '{{project_start_date}}'
{% endif %}
)
select distinct
block_time,
date_trunc('day', block_time) as block_date,
date_trunc('month', block_time) as block_month,
'{{blockchain}}' as blockchain,
-- Trade
amount_usd,
type,
token_bought_amount,
token_bought_symbol,
cast(token_bought_address as varchar) as token_bought_address,
token_sold_amount,
token_sold_symbol,
cast(token_sold_address as varchar) as token_sold_address,
-- Fees
fee_token_amount / power(10, decimals) * price as fee_usd,
fee_token_amount / power(10, decimals) as fee_token_amount,
symbol as fee_token_symbol,
cast(fee_token_address as varchar) as fee_token_address,
-- Dex
project,
version,
token_pair,
cast(project_contract_address as varchar) as project_contract_address,
-- User
cast(user as varchar) as user,
cast(bot_trades.tx_hash as varchar) as tx_hash,
evt_index,
if(evt_index = highest_event_index, true, false) as is_last_trade_in_transaction
from bot_trades
join
highest_event_index_for_each_trade
on bot_trades.tx_hash = highest_event_index_for_each_trade.tx_hash
/* Left Outer Join to support 0 fee trades */
left join fee_deposits on bot_trades.tx_hash = fee_deposits.evt_tx_hash
left join
{{ source('prices', 'usd') }}
on (
blockchain = '{{blockchain}}'
and contract_address = fee_token_address
and minute = date_trunc('minute', block_time)
)
order by block_time desc, evt_index desc
Loading
Loading