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

Alw joe v2 data #529

Draft
wants to merge 6 commits into
base: main
Choose a base branch
from
Draft
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
70 changes: 70 additions & 0 deletions macros/trader_joe_v_2/trader_joe_v_2_1_swaps.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,70 @@
{% macro get_trader_joe_v_2_1_swaps_for_chain(factory_address, chain, version) %}

WITH lbpairs AS ( -- Step 1: Extract all Pools addresses that were created in the factory contract ``
SELECT
DECODED_LOG:"LBPair" :: string AS lbpair_address,
DECODED_LOG:"tokenX" :: string AS token_X_address,
DECODED_LOG:"tokenY" :: string AS token_Y_address
FROM
{{chain}}_flipside.core.ez_decoded_event_logs
WHERE
LOWER(contract_address) = LOWER('{{factory_address}}') -- factory contract
AND event_name = 'LBPairCreated' -- get all pools made in this version
)
,swaps AS ( -- Step 2: Use the extracted LBPair addresses to filter Swap events
SELECT
block_timestamp,
tx_hash,
origin_from_address,
CONTRACT_ADDRESS as lbpair_address,
PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(DECODED_LOG:"amountsIn" :: string, 3, 32)) AS amount_Y, -- first 128 bits is Y
PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(DECODED_LOG:"amountsIn" :: string, 35, 32)) AS amount_X, -- last 128 bits from the right is X

PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(DECODED_LOG:"totalFees":: string, 3, 32))::number AS fees_Y,
PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(DECODED_LOG:"totalFees":: string, 35, 32))::number AS fees_X,
fees_Y + fees_X as native_fees,

PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(DECODED_LOG:"protocolFees":: string, 3, 32))::number AS protocol_fees_Y,
PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(DECODED_LOG:"protocolFees":: string, 35, 32))::number AS protocol_fees_X,
protocol_fees_Y + protocol_fees_X as protocol_fees
FROM
{{chain}}_flipside.core.ez_decoded_event_logs
WHERE
LOWER(contract_address) IN (
SELECT lbpair_address FROM lbpairs
)
AND event_name = 'Swap'
{% if is_incremental() %}
AND block_timestamp > (SELECT MAX(block_timestamp) FROM {{this}})
{% endif %}
)
SELECT
s.block_timestamp,
'{{chain}}' as chain,
'{{version}}' as version,
'trader_joe' as app,
s.tx_hash,
s.origin_from_address as user_address,
s.lbpair_address,
s.amount_Y,
s.fees_Y,
s.amount_X,
s.fees_X,
l.token_X_address,
l.token_Y_address,
((s.amount_Y + s.amount_X) * p.price) / pow(10,p.decimals) as volume_usd,
(s.native_fees * p.price) / pow(10,p.decimals) as fee_usd,
(s.protocol_fees * p.price) / pow(10, p.decimals) as protocol_fees_usd,
p.symbol,
p.price,
CASE
WHEN s.amount_Y = '0' THEN token_X_address -- amountY is a string. When Y is 0, you swap X for Y -> fee paid in X
ELSE token_Y_address
END AS fee_token_address
FROM
swaps s
left join lbpairs l ON s.lbpair_address = l.lbpair_address
left join {{chain}}_flipside.price.ez_prices_hourly p ON date_trunc('hour', block_timestamp) = p.hour
AND p.token_address = fee_token_address

{% endmacro %}
74 changes: 74 additions & 0 deletions macros/trader_joe_v_2/trader_joe_v_2_2_swaps.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
{% macro get_trader_joe_v_2_2_swaps_for_chain(factory_address, chain, version) %}
WITH lbpairs AS ( -- Step 1: Extract all Pools addresses that were created in the factory contract ``
SELECT
DECODED_LOG:"LBPair" :: string AS lbpair_address,
DECODED_LOG:"tokenX" :: string AS token_X_address,
DECODED_LOG:"tokenY" :: string AS token_Y_address
FROM
{{chain}}_flipside.core.ez_decoded_event_logs
WHERE
LOWER(contract_address) = LOWER('{{factory_address}}') -- factory contract
AND event_name = 'LBPairCreated' -- get all pools made in this version
)
, swaps AS ( -- Step 2: Use the extracted LBPair addresses to filter Swap events
SELECT
block_timestamp
, tx_hash
, origin_from_address
, contract_address as lbpair_address
, substr(data, 3, 64) as id
, substr(data, 67, 64) as amountIn
, PC_DBT_DB.PROD.HEX_TO_INT(substr(amountIn, 1, 32)) as amount_Y
, PC_DBT_DB.PROD.HEX_TO_INT(substr(amountIn, 33, 32)) as amount_X
, substr(data, 259, 64) as totalFees
, substr(data, 323, 64) as protocolFees
, PC_DBT_DB.PROD.HEX_TO_INT(substr(totalFees, 1, 32)) as fees_Y
, PC_DBT_DB.PROD.HEX_TO_INT(substr(totalFees, 33, 32)) as fees_X
, fees_Y + fees_X as native_fees
, PC_DBT_DB.PROD.HEX_TO_INT(substr(protocolFees, 1, 32)) as protocol_fees_Y
, PC_DBT_DB.PROD.HEX_TO_INT(substr(protocolFees, 33, 32)) as protocol_fees_X
, protocol_fees_Y + protocol_fees_X as protocol_fees
FROM
{{chain}}_flipside.core.fact_event_logs
WHERE
LOWER(contract_address) IN (
SELECT
lbpair_address
FROM
lbpairs
)
AND topics[0] = '0xad7d6f97abf51ce18e17a38f4d70e975be9c0708474987bb3e26ad21bd93ca70'
{% if is_incremental() %}
AND block_timestamp > (SELECT MAX(block_timestamp) FROM {{this}})
{% endif %}
)
SELECT
s.block_timestamp,
'{{chain}}' as chain,
'{{version}}' as version,
'trader_joe' as app,
s.tx_hash,
s.origin_from_address as user_address,
s.lbpair_address,
s.amount_Y,
s.fees_Y,
s.amount_X,
s.fees_X,
l.token_X_address,
l.token_Y_address,
((s.amount_Y + s.amount_X) * p.price) / pow(10,p.decimals) as volume_usd,
(s.native_fees * p.price) / pow(10,p.decimals) as fee_usd,
(s.protocol_fees *p.price) / pow(10, p.decimals) as protocol_fees_usd,
p.symbol,
p.price,
CASE
WHEN s.amount_Y = '0' THEN token_X_address -- amountY is a string. When Y is 0, you swap X for Y -> fee paid in X
ELSE token_Y_address
END AS fee_token_address
FROM
swaps s
left join lbpairs l ON s.lbpair_address = l.lbpair_address
left join {{chain}}_flipside.price.ez_prices_hourly p ON date_trunc('hour', block_timestamp) = p.hour
AND p.token_address = fee_token_address

{% endmacro %}
76 changes: 76 additions & 0 deletions models/projects/trader_joe/core/ez_trader_joe_metrics.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,76 @@
{{
config(
materialized="table",
snowflake_warehouse="TRADER_JOE",
database="trader_joe",
schema="core",
alias="ez_metrics",
)
}}

with
v2_tvl as (
Comment on lines +1 to +12
Copy link
Contributor

Choose a reason for hiding this comment

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

Can add a comment in the ez_metrics... about the differences in the ez_metrics_by_chain and the ez_metrics model. If I remember from our convo ez_metrics_by_chain does not include the v2 or greater data?

can you also add a note in ez_dex_swaps?

with agg as (
select
date,
avg(tvl) as tvl
from
pc_dbt_db.prod.fact_defillama_protocol_tvls
where
defillama_protocol_id in (
select
distinct id
from
pc_dbt_db.prod.fact_defillama_protocols
where
name in ('Joe V2.1', 'Joe V2.2', 'Joe V2')
)
group by date
)
SELECT date(date) as date, sum(tvl) as tvl FROM agg
group by 1 order by 1 desc
)
, v2_data as (
select
date,
sum(total_volume) as total_volume,
sum(total_fees) as total_fees,
sum(protocol_fees) as protocol_fees,
sum(unique_traders) as unique_traders,
sum(daily_txns) as daily_txns
from {{ ref("fact_trader_joe_v2_all_versions_metrics")}}
group by 1
)
, ez_metrics_agg as (
select
date(date) as date,
app,
category,
sum(tvl) as tvl,
sum(trading_volume) as trading_volume,
sum(trading_fees) as trading_fees,
sum(unique_traders) as unique_traders,
sum(gas_cost_native) as gas_cost_native,
sum(gas_cost_usd) as gas_cost_usd,
sum(txns) as txns
from {{ref("ez_trader_joe_metrics_by_chain")}}
group by 1, 2, 3
)

select
date(coalesce(v2_tvl.date, e.date)) as date,
app,
category,
sum(coalesce(e.tvl,0) + coalesce(v2_tvl.tvl, 0)) as tvl,
sum(coalesce(e.trading_volume, 0) + coalesce(v2_data.total_volume, 0)) as trading_volume,
sum(coalesce(e.trading_fees, 0) + coalesce(v2_data.total_fees, 0)) as trading_fees,
sum(coalesce(v2_data.protocol_fees, 0)) as revenue,
sum(coalesce(e.unique_traders, 0) + coalesce(v2_data.unique_traders, 0)) as unique_traders,
sum(coalesce(e.gas_cost_native, 0)) as gas_cost_native,
sum(coalesce(e.gas_cost_usd, 0)) as gas_cost_usd,
sum(coalesce(e.txns, 0) + coalesce(v2_data.daily_txns, 0)) as txns
from ez_metrics_agg e
left join v2_data using (date)
left join v2_tvl using (date)
group by 1, 2, 3
order by 1 desc
Original file line number Diff line number Diff line change
Expand Up @@ -57,19 +57,20 @@ with
from {{ ref("ez_trader_joe_dex_swaps")}}
group by 1, 2
)

select
tvl_by_chain.date,
'trader_joe' as app,
'DeFi' as category,
tvl_by_chain.chain,
tvl_by_chain.tvl,
trading_volume_by_chain.trading_volume,
trading_volume_by_chain.trading_fees,
trading_volume_by_chain.unique_traders,
coalesce(trading_volume_by_chain.trading_volume, 0) as trading_volume,
coalesce(trading_volume_by_chain.trading_fees, 0) as trading_fees,
coalesce(trading_volume_by_chain.unique_traders, 0) as unique_traders,
trading_volume_by_chain.gas_cost_native,
trading_volume_by_chain.gas_cost_usd,
daily_txns_data.daily_txns as txns
coalesce(daily_txns_data.daily_txns, 0) as txns
from tvl_by_chain
left join trading_volume_by_chain using(date, chain)
left join daily_txns_data using (date, chain)
where tvl_by_chain.date < to_date(sysdate())
where tvl_by_chain.date < to_date(sysdate())
7 changes: 7 additions & 0 deletions models/staging/trader_joe/__trader_joe_sources__.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
sources:
- name: PROD_LANDING
schema: PROD_LANDING
database: LANDING_DATABASE
tables:
- name: raw_trader_joe_arbitrum_v2_0_metrics
- name: raw_trader_joe_avalanche_v2_0_metrics
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
{{
config(
materialized="incremental",
snowflake_warehouse="TRADER_JOE",
)
}}

{{get_trader_joe_v_2_1_swaps_for_chain('0x8e42f2F4101563bF679975178e880FD87d3eFd4e', 'arbitrum', 'v2.1')}}
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
{{
config(
materialized="incremental",
snowflake_warehouse="TRADER_JOE",
)
}}

{{get_trader_joe_v_2_2_swaps_for_chain('0xb43120c4745967fa9b93E79C149E66B0f2D6Fe0c', 'arbitrum', 'v2.2')}}
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
{{
config(
materialized="incremental",
snowflake_warehouse="TRADER_JOE",
)
}}

{{get_trader_joe_v_2_1_swaps_for_chain('0x8e42f2F4101563bF679975178e880FD87d3eFd4e', 'avalanche', 'v2.1')}}
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
{{
config(
materialized="incremental",
snowflake_warehouse="TRADER_JOE",
)
}}

{{get_trader_joe_v_2_2_swaps_for_chain('0xb43120c4745967fa9b93E79C149E66B0f2D6Fe0c', 'avalanche', 'v2.2')}}
Original file line number Diff line number Diff line change
@@ -0,0 +1,44 @@
{{
config(
materialized='table',
snowflake_warehouse='TRADER_JOE'
)
}}

with all_versions_metrics as (
SELECT
date,
chain,
version,
unique_traders,
daily_txns,
total_volume,
total_fees,
protocol_fees
FROM {{ref('fact_trader_joe_v_2_1_metrics')}}

UNION ALL

SELECT
date,
chain,
version,
unique_traders,
daily_txns,
total_volume,
total_fees,
protocol_fees
FROM {{ref('fact_trader_joe_v_2_2_metrics')}}
)
SELECT
date,
chain,
version,
sum(coalesce(unique_traders, 0)) as unique_traders,
sum(coalesce(daily_txns, 0)) as daily_txns,
sum(total_volume) as total_volume,
sum(total_fees) as total_fees,
sum(protocol_fees) as protocol_fees
FROM all_versions_metrics
GROUP BY 1, 2, 3
ORDER BY 1 DESC
11 changes: 11 additions & 0 deletions models/staging/trader_joe/fact_trader_joe_v_2_1_dex_swaps.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{{
config(
materialized='table',
snowflake_warehouse='TRADER_JOE'
)
}}


SELECT * FROM {{ref('fact_trader_joe_avalanche_v2_1_dex_swaps')}}
UNION ALL
SELECT * FROM {{ref('fact_trader_joe_arbitrum_v2_1_dex_swaps')}}
19 changes: 19 additions & 0 deletions models/staging/trader_joe/fact_trader_joe_v_2_1_metrics.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
{{
config(
materialized='table',
snowflake_warehouse='TRADER_JOE'
)
}}

SELECT
date(block_timestamp) AS date,
chain,
version,
count(distinct user_address) as unique_traders,
count(*) as daily_txns,
sum(volume_usd) as total_volume,
sum(fee_usd) as total_fees,
sum(protocol_fees_usd) as protocol_fees
FROM {{ref('fact_trader_joe_v_2_1_dex_swaps')}}
GROUP BY 1, 2, 3
ORDER BY 1 DESC
11 changes: 11 additions & 0 deletions models/staging/trader_joe/fact_trader_joe_v_2_2_dex_swaps.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{{
config(
materialized='table',
snowflake_warehouse='TRADER_JOE'
)
}}


SELECT * FROM {{ref('fact_trader_joe_avalanche_v2_2_dex_swaps')}}
UNION ALL
SELECT * FROM {{ref('fact_trader_joe_arbitrum_v2_2_dex_swaps')}}
Loading
Loading