Skip to content

Commit

Permalink
Adding new tables to CoW Protocol Arbitrum chain (duneanalytics#6224)
Browse files Browse the repository at this point in the history
* Update cow_protocol_arbitrum_sources.yml

Adding new sources for arbitrum

* Create cow_protocol_gnosis_solvers.sql

Adding solvers tables for arbitrum

* Create cow_protocol_arbitrum_batches.sql

adding bacthes tables

* Rename cow_protocol_gnosis_solvers.sql to cow_protocol_arbitrum_solvers.sql

fix in name

* Create cow_protocol_arbitrum_schema.yml

Adding schema

* Update cow_protocol_batches.sql

* Update cow_protocol_arbitrum_sources.yml

Fixing duplicated anchor

* Update cow_protocol_arbitrum_sources.yml

* Update cow_protocol_arbitrum_batches.sql

* Update cow_protocol_batches.sql

removing Arbitrum due to DBT compile error

* Update cow_protocol_batches.sql

Adding batches to the joined table

* Update cow_protocol_arbitrum_batches.sql

Change the alias Configuration due to DBT error

* Update cow_protocol_arbitrum_batches.sql

Changing table reference

* Update cow_protocol_arbitrum_batches.sql

removing table dependancy

* Update cow_protocol_arbitrum_batches.sql

* Update cow_protocol_arbitrum_batches.sql

Typo in a table

* Update cow_protocol_arbitrum_batches.sql

Gnosis to Arbitrum change

* Update models/cow_protocol/arbitrum/cow_protocol_arbitrum_batches.sql

Co-authored-by: Huang Geyang <[email protected]>

* Update models/cow_protocol/arbitrum/cow_protocol_arbitrum_solvers.sql

Co-authored-by: Huang Geyang <[email protected]>

* Update models/cow_protocol/arbitrum/cow_protocol_arbitrum_solvers.sql

Co-authored-by: Huang Geyang <[email protected]>

* Update models/cow_protocol/arbitrum/cow_protocol_arbitrum_batches.sql

Co-authored-by: Huang Geyang <[email protected]>

* Update cow_protocol_arbitrum_schema.yml

Adding Uniqnuess test for cow_protocol_arbitrum.batches table

* add arbitrum to sources

* Update cow_protocol_arbitrum_batches.sql

Using jinja source syntax to update the file

* Update cow_protocol_arbitrum_schema.yml

Checking uniqueness of the PK

* Update cow_protocol_arbitrum_batches.sql

Removing duplicated syntax

* Update cow_protocol_arbitrum_batches.sql

Reverting the hardcoded logic back.

---------

Co-authored-by: Huang Geyang <[email protected]>
Co-authored-by: jeff-dude <[email protected]>
  • Loading branch information
3 people authored Jun 27, 2024
1 parent b59336b commit e0c5a45
Show file tree
Hide file tree
Showing 6 changed files with 307 additions and 14 deletions.
125 changes: 125 additions & 0 deletions models/cow_protocol/arbitrum/cow_protocol_arbitrum_batches.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,125 @@
{{ config(
schema = 'cow_protocol_arbitrum',
alias = 'batches',
materialized='incremental',
partition_by = ['block_date'],
unique_key = ['tx_hash'],
on_schema_change='sync_all_columns',
file_format ='delta',
incremental_strategy='merge',
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')],
post_hook='{{ expose_spells(blockchains = \'["arbitrum"]\',
spell_type = "project",
spell_name = "cow_protocol",
contributors = \'["olgafetisova"]\') }}'
)
}}

WITH
-- Find the PoC Query here: https://dune.com/queries/3840594
solver_activation_events AS (
SELECT
solver,
evt_block_number,
evt_index,
TRUE AS activated
FROM {{ source('gnosis_protocol_v2_arbitrum', 'GPv2AllowListAuthentication_evt_SolverAdded') }}
UNION
SELECT
solver,
evt_block_number,
evt_index,
FALSE AS activated
FROM {{ source('gnosis_protocol_v2_arbitrum', 'GPv2AllowListAuthentication_evt_SolverRemoved') }}
),
ranked_solver_events as (
select
rank() over (partition by solver order by evt_block_number desc, evt_index desc) as rk,
solver,
evt_block_number,
evt_index,
activated as active
from solver_activation_events
),
registered_solvers as (
select solver as address, active
from ranked_solver_events
where rk = 1
),
batch_counts as (
select try_cast(date_trunc('day', s.evt_block_time) as date) as block_date,
s.evt_block_time,
s.evt_tx_hash,
solver,
sum(
case
when selector != 0x2e1a7d4d -- unwrap
and selector != 0x095ea7b3 -- approval
then 1
else 0
end) as dex_swaps,
sum(case when selector = 0x2e1a7d4d then 1 else 0 end) as unwraps,
sum(case when selector = 0x095ea7b3 then 1 else 0 end) as token_approvals
from {{ source('gnosis_protocol_v2_arbitrum', 'GPv2Settlement_evt_Settlement') }} s
left outer join {{ source('gnosis_protocol_v2_arbitrum', 'GPv2Settlement_evt_Interaction') }} i
on i.evt_tx_hash = s.evt_tx_hash
{% if is_incremental() %}
AND {{ incremental_predicate('i.evt_block_time') }}
{% endif %}
join registered_solvers
on solver = address
{% if is_incremental() %}
WHERE {{ incremental_predicate('s.evt_block_time') }}
{% endif %}
group by s.evt_tx_hash, solver, s.evt_block_time
),

batch_values as (
select
tx_hash,
count(*) as num_trades,
sum(usd_value) as batch_value,
sum(fee_usd) as fee_value,
price as eth_price
from {{ source('cow_protocol_arbitrum', 'trades') }}
left outer join {{ source('prices', 'usd') }} as p
on p.contract_address = 0x82af49447d8a07e3bd95bd0d56f35241523fbab1
{% if is_incremental() %}
and {{ incremental_predicate('minute') }}
{% endif %}
and p.minute = date_trunc('minute', block_time)
and blockchain = 'arbitrum'
{% if is_incremental() %}
WHERE {{ incremental_predicate('block_time') }}
{% endif %}
group by tx_hash, price
),

combined_batch_info as (
select
b.block_date,
evt_block_time as block_time,
num_trades,
dex_swaps,
batch_value,
solver as solver_address,
evt_tx_hash as tx_hash,
gas_price,
gas_used,
((gas_price / pow(10, 9)) * gas_used * eth_price) / pow(10, 9) as tx_cost_usd,
fee_value,
2 * bytearray_length(data) / 1024 as call_data_size,
unwraps,
token_approvals
from batch_counts b
join batch_values t
on b.evt_tx_hash = t.tx_hash
inner join {{ source('arbitrum', 'transactions') }} tx
on evt_tx_hash = hash
{% if is_incremental() %}
AND {{ incremental_predicate('tx.block_time') }}
{% endif %}
where num_trades > 0 --! Exclude Withdraw Batches
)

select * from combined_batch_info
25 changes: 25 additions & 0 deletions models/cow_protocol/arbitrum/cow_protocol_arbitrum_schema.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
version: 2

models:
- name: cow_protocol_arbitrum_solvers
meta:
blockchain: arbitrum
project: cow_protocol
contributors: olgafetisova
config:
tags: ['arbitrum_chain','cow_protocol','solver']
description: >
CoW Protocol solvers list on Arbitrum Chain
- name: cow_protocol_arbitrum_batches
meta:
blockchain: arbitrum
project: cow_protocol
contributors: olgafetisova
config:
tags: ['arbitrum','cow_protocol','trades', 'dex', 'aggregator', 'auction']
description: >
CoW Protocol enriched batches table on Arbitrum Chain
tests:
- unique:
column_name: tx_hash
72 changes: 72 additions & 0 deletions models/cow_protocol/arbitrum/cow_protocol_arbitrum_solvers.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,72 @@
{{ config(
schema = 'cow_protocol_arbitrum',
alias='solvers',
post_hook='{{ expose_spells(blockchains = \'["arbitrum"]\',
spell_type = "project",
spell_name = "cow_protocol",
contributors = \'["olgafetisova"]\') }}'
)}}

-- Find the PoC Query here: https://dune.com/queries/3840597
WITH
-- Aggregate the solver added and removed events into a single table
-- with true/false for adds/removes respectively
solver_activation_events as (
select solver, evt_block_number, evt_index, True as activated
from {{ source('gnosis_protocol_v2_arbitrum', 'GPv2AllowListAuthentication_evt_SolverAdded') }}
union
select solver, evt_block_number, evt_index, False as activated
from {{ source('gnosis_protocol_v2_arbitrum', 'GPv2AllowListAuthentication_evt_SolverRemoved') }}
),
-- Sorting by (evt_block_number, evt_index) allows us to pick the most recent activation status of each unique solver
ranked_solver_events as (
select
rank() over (partition by solver order by evt_block_number desc, evt_index desc) as rk,
solver,
evt_block_number,
evt_index,
activated as active
from solver_activation_events
),
registered_solvers as (
select solver, active
from ranked_solver_events
where rk = 1
),
-- Manually inserting environment and name for each "known" solver
known_solver_metadata (address, environment, name) as (
SELECT *
FROM (VALUES
(0xA70892d1Af41aBD2F648FEC74Ea2c17e56Ac3B9A, 'prod', 'Naive'),
(0xba36CEfb45d1CdD2Ae30a899C432c5081E095Ff8, 'prod', 'Baseline'),
(0xF017C6F66D68d11AF00FD243494E3fa0EBf44C66, 'prod', 'Quasimodo'),
(0x001088C88be46346ED99856dcfA3a00Da7AAf212, 'prod', '1Inch'),
(0xc46Ac109FDe084192BE59C24C3680D818763b0fd, 'prod', 'ParaSwap'),
(0xD31E0CE8154Da6b8086d961eB3068Ef74C4322b6, 'prod', '0x'),
(0xAa224676d096B6Fc257F8C386C67d9e96e53AD59, 'prod', 'BalancerSOR'),
(0x5932b2c05172aAfE097CE0Fbd27d18a7d5A45eE1, 'prod', 'Furucombo'),
(0x3A485742Bd85e660e72dE0f49cC27AD7a62911B5, 'prod', 'SeaSolver'),
(0x059aefdF9d9F47def37cF7066DA83fEB91fDd089, 'prod', 'Barter'),
(0x40798d2261f8b7F11BFa73623c99C876844dD05A, 'prod', 'OpenOcean'),
(0x0648548f891E1356f197070D009704e574182bfB, 'prod', 'Rizzolver'),
(0x20dC1014E946Cf511Ee535D908eC9a1d75Dd66ce, 'barn', 'Naive'),
(0x2e6822f4Ab355E386d1A4fd34947ACE0F6f344a7, 'barn', 'Baseline'),
(0x03a65D265E0613326ca23f5E6A1a99Ab2F12600B, 'barn', 'Quasimodo'),
(0xee10E8D38150BEe3b0B32c41b74821d6e7Da485A, 'barn', '1Inch'),
(0x9C803d345615aDe1e5ae07A789968403fAc9171a, 'barn', 'ParaSwap'),
(0x69433b336952e84Db44EF40b16B338F139B8baA1, 'barn', '0x'),
(0xCED55FC88186f672105712fe177374cce4861FDF, 'barn', 'BalancerSOR'),
(0xE376a730037D8B495864FD5ed6373BE89643cD06, 'barn', 'Furucombo'),
(0x2633bd8e5FDf7C72Aca1d291CA11bdB717A6aa3d, 'barn', 'SeaSolver'),
(0x7B0211286d8Dfdb717f4A2E5Fa5131eD911097e1, 'barn', 'Barter'),
(0xc8371B2898FBaEeAe658f9FaeE8ddeDA24e37012, 'barn', 'OpenOcean'),
(0x2aeC288B42C99D2e8e984c5C324FB069f7705186, 'barn', 'Rizzolver')
) as _
)
-- Combining the metadata with current activation status for final table
select solver as address,
case when environment is not null then environment else 'new' end as environment,
case when name is not null then name else 'Uncatalogued' end as name,
active
from registered_solvers
left outer join known_solver_metadata on solver = address;
26 changes: 24 additions & 2 deletions models/cow_protocol/cow_protocol_batches.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,7 @@
post_hook='{{ expose_spells(\'["ethereum", "gnosis"]\',
"project",
"cow_protocol",
\'["bh2smith", "gentrexha"]\') }}'
\'["bh2smith", "gentrexha", "olgafetisova"]\') }}'
)
}}
SELECT *
Expand Down Expand Up @@ -51,4 +51,26 @@ FROM
unwraps,
token_approvals
FROM {{ ref('cow_protocol_gnosis_batches') }}
)

UNION ALL

SELECT
'arbitrum' AS blockchain,
'cow_protocol' AS project,
'1' AS version,
block_date,
block_time,
num_trades,
dex_swaps,
batch_value,
solver_address,
tx_hash,
gas_price,
gas_used,
tx_cost_usd,
fee_value,
call_data_size,
unwraps,
token_approvals
FROM {{ ref('cow_protocol_arbitrum_batches') }}
)
3 changes: 3 additions & 0 deletions sources/_subprojects/dex/_sources.yml
Original file line number Diff line number Diff line change
Expand Up @@ -63,5 +63,8 @@ sources:
tables:
- name: trades
- name: cow_protocol_gnosis
tables:
- name: trades
- name: cow_protocol_arbitrum
tables:
- name: trades
70 changes: 58 additions & 12 deletions sources/cow_protocol/arbitrum/cow_protocol_arbitrum_sources.yml
Original file line number Diff line number Diff line change
Expand Up @@ -4,21 +4,15 @@ sources:
- name: gnosis_protocol_v2_arbitrum
description: "Arbitrum Chain decoded tables related to CoW Protocol contract"
tables:
- name: GPv2Settlement_evt_Trade
description: "Trade events emitted by GPv2Settlement"
- name: GPv2AllowListAuthentication_evt_SolverAdded
description: "GPv2AllowListAuthentication list of events when a Solver was added"
columns:
- &feeAmount
name: feeAmount
description: "Amount (in sell token) in atoms of the trade fee"
- &buyAmount
name: buyAmount
description: "Amount (in atoms) of the buyToken bought"
- &buyToken
name: buyToken
description: "Contract address of token obtained in trade"
- &solver
name: solver
description: "Solver wallet address"
- &contract_address
name: contract_address
description: "Ethereum address of contract emitting the event"
description: "Arbitrum address of contract emitting the event"
- &evt_block_number
name: evt_block_number
description: "Block number which processed the unique transaction hash"
Expand All @@ -33,6 +27,32 @@ sources:
description: "Primary key of the transaction"
tests:
- not_null
- name: GPv2AllowListAuthentication_evt_SolverRemoved
description: "GPv2AllowListAuthentication list of events when a solver was removed"
columns:
- *solver
- *contract_address
- *evt_block_number
- *evt_block_time
- *evt_index
- *evt_tx_hash
- name: GPv2Settlement_evt_Trade
description: "Trade events emitted by GPv2Settlement"
columns:
- &feeAmount
name: feeAmount
description: "Amount (in sell token) in atoms of the trade fee"
- &buyAmount
name: buyAmount
description: "Amount (in atoms) of the buyToken bought"
- &buyToken
name: buyToken
description: "Contract address of token obtained in trade. 0xeee...ee represents native asset ETH"
- *contract_address
- *evt_block_number
- *evt_block_time
- *evt_index
- *evt_tx_hash
- &orderUid
name: orderUid
description: "Unique identifier of order involved in trade. Note that partially fillable orders can be touched multiple times so this is not a unique ID for trade events."
Expand Down Expand Up @@ -76,3 +96,29 @@ sources:
- &trades
name: trades
description: "An array of order data for the trades being executed"
- name: GPv2Settlement_evt_Settlement
description: "Settlement events emitted by GPv2Settlement"
columns:
- *contract_address
- *evt_block_number
- *evt_block_time
- *evt_index
- *evt_tx_hash
- *solver
- name: GPv2Settlement_evt_Interaction
description: "Contract Interaction events emitted by GPv2Settlement"
columns:
- *contract_address
- *evt_block_number
- *evt_block_time
- *evt_index
- *evt_tx_hash
- &selector
name: selector
description: Method ID of the contract being interacted with
- &target
name: target
description: Target contract address of the interaction
- &value
name: value
description: ETH amount (in WEI) being passed into contract interaction

0 comments on commit e0c5a45

Please sign in to comment.