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

Uniswap V4 dex liquidity (ethereum) #7644

Merged
merged 39 commits into from
Feb 14, 2025
Merged
Show file tree
Hide file tree
Changes from 35 commits
Commits
Show all changes
39 commits
Select commit Hold shift + click to select a range
d5a3e10
Uniswap V4 dex liquidity (ethereum)
IrishLatte19 Feb 12, 2025
51d16a9
Update _schema.yml
IrishLatte19 Feb 12, 2025
af13d6d
Rename dex.liquidity.sql to dex_liquidity.sql
IrishLatte19 Feb 12, 2025
fc7f22d
Update _schema.yml
IrishLatte19 Feb 12, 2025
00703f0
Update enrich_dex_liq_with_prices.sql
IrishLatte19 Feb 12, 2025
a680a0c
Update dex_liquidity.sql
IrishLatte19 Feb 12, 2025
5bc9cf5
Update _schema.yml
IrishLatte19 Feb 12, 2025
af2a0de
Uniswap V4 dex liquidity (ethereum)
IrishLatte19 Feb 12, 2025
9747967
Update _sources.yml
IrishLatte19 Feb 12, 2025
53a2c24
Update enrich_dex_liq_with_prices.sql
IrishLatte19 Feb 12, 2025
e707f2e
Update uniswap_compatible_liquidity.sql
IrishLatte19 Feb 12, 2025
9befb95
Update uniswap_compatible_liquidity.sql
IrishLatte19 Feb 12, 2025
340c775
Update dex_ethereum_base_liquidity.sql
IrishLatte19 Feb 12, 2025
0fb2289
Update uniswap_compatible_liquidity.sql
IrishLatte19 Feb 12, 2025
ecc67e1
Update uniswap_compatible_liquidity.sql
IrishLatte19 Feb 12, 2025
6c14fd4
Uniswap V4 dex liquidity (ethereum)
IrishLatte19 Feb 12, 2025
85fbe2b
Update uniswap_ethereum_base_liquidity_seed.csv
IrishLatte19 Feb 12, 2025
1283529
Update uniswap_ethereum_base_liquidity_seed.csv
IrishLatte19 Feb 12, 2025
8c07783
Update _schema.yml
IrishLatte19 Feb 12, 2025
033754d
Update uniswap_compatible_liquidity.sql
IrishLatte19 Feb 12, 2025
4ef8ee8
Update uniswap_compatible_liquidity.sql
IrishLatte19 Feb 12, 2025
0728b4c
Update dex_ethereum_base_liquidity.sql
IrishLatte19 Feb 12, 2025
1fd6c01
Update _schema.yml
IrishLatte19 Feb 12, 2025
ad4b70a
Update _schema.yml
IrishLatte19 Feb 12, 2025
a43c116
Update uniswap_compatible_liquidity.sql
IrishLatte19 Feb 12, 2025
3b21c91
Update dex_liquidity.sql
IrishLatte19 Feb 12, 2025
6981191
Update dex_liquidity.sql
IrishLatte19 Feb 12, 2025
1430ab5
Update enrich_dex_liq_with_prices.sql
IrishLatte19 Feb 12, 2025
96da6f5
Update enrich_dex_liq_with_prices.sql
IrishLatte19 Feb 12, 2025
9cfbfc4
Merge branch 'main' into Irishlatte
IrishLatte19 Feb 12, 2025
939150a
Update _schema.yml
IrishLatte19 Feb 12, 2025
1fd36f2
Update _schema.yml
IrishLatte19 Feb 12, 2025
6c07913
Update enrich_dex_liq_with_prices.sql
IrishLatte19 Feb 12, 2025
d70b460
Uniswap V4 dex liquidity (ethereum)
IrishLatte19 Feb 12, 2025
dceae7f
Update dex_base_liquidity.sql
IrishLatte19 Feb 12, 2025
96f4705
Testing liquidity with filtered swaps
Hosuke Feb 13, 2025
3010c9b
Update dbt_subprojects/dex/macros/models/_project/uniswap_compatible_…
Hosuke Feb 13, 2025
5c96714
Simplify uniswap_compatible_liquidity.sql
Hosuke Feb 14, 2025
52942a6
Update enrich_dex_liq_with_prices.sql
IrishLatte19 Feb 14, 2025
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
Original file line number Diff line number Diff line change
@@ -0,0 +1,96 @@
{% macro uniswap_compatible_v4_liquidity(
blockchain = null
, project = 'uniswap'
, version = '4'
, PoolManager_evt_ModifyLiquidity = null
, PoolManager_evt_Swap = null
, PoolManager_evt_Initialize = null
, pair_column_name = 'id'
)
%}
WITH get_recent_sqrtPriceX96 AS
(
SELECT *
FROM (
SELECT
ml.*
,i.currency0 as token0
, i.currency1 as token1
, COALESCE(s.evt_block_time, i.evt_block_time) as most_recent_time
, COALESCE(s.sqrtPriceX96, i.sqrtPriceX96) AS sqrtPriceX96
, ROW_NUMBER() OVER (
PARTITION BY ml.id, ml.evt_block_time
ORDER BY
CASE WHEN s.sqrtPriceX96 IS NOT NULL THEN s.evt_block_time ELSE i.evt_block_time END DESC
) AS rn
FROM
{{ PoolManager_evt_ModifyLiquidity }} ml
LEFT JOIN
{{ PoolManager_evt_Swap }} s ON ml.evt_block_time > s.evt_block_time AND ml.id = s.id
LEFT JOIN
{{ PoolManager_evt_Initialize }} i ON ml.evt_block_time >= i.evt_block_time AND i.{{pair_column_name}} = ml.id
{%- if is_incremental() %}
WHERE
{{ incremental_predicate('ml.evt_block_time') }}
{%- endif %}
Copy link
Collaborator

Choose a reason for hiding this comment

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

Do you need full PoolManager_evt_Swap and PoolManager_evt_Initialize table for left join?

If not we may filter out in another CTE first.

Copy link
Contributor Author

@IrishLatte19 IrishLatte19 Feb 13, 2025

Choose a reason for hiding this comment

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

Ummm It's being joined on id (pool in this case).
How would you suggest to do it in another CTE? 🤔

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 will do a experimental spell in parallel to test the output first.

Currently it seems like [incremental evt_ModifyLiquidity] x [full evt_Swap] x [full evt_Initialize].

I may try with if [incremental evt_ModifyLiquidity] x [incremental evt_Swap] x [full evt_Initialize] output the same.

Copy link
Collaborator

@Hosuke Hosuke Feb 13, 2025

Choose a reason for hiding this comment

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

Maybe we can try this in a parallel spell:

WITH filtered_swaps AS (
    SELECT 
        evt_block_time,
        id,
        sqrtPriceX96
    FROM {{ PoolManager_evt_Swap }}
    {%- if is_incremental() %}
    WHERE {{ incremental_predicate('evt_block_time') }}
    {%- endif %}
),

get_recent_sqrtPriceX96 AS
(
    SELECT *
      FROM (
                SELECT 
                        ml.*
                        ,i.currency0 as token0
                        , i.currency1 as token1
                        , COALESCE(s.evt_block_time, i.evt_block_time) as most_recent_time
                        , COALESCE(s.sqrtPriceX96, i.sqrtPriceX96) AS sqrtPriceX96
                        , ROW_NUMBER() OVER (
                            PARTITION BY ml.id, ml.evt_block_time
                            ORDER BY 
                                CASE WHEN s.sqrtPriceX96 IS NOT NULL THEN s.evt_block_time ELSE i.evt_block_time END DESC
                        ) AS rn
                    FROM 
                        {{ PoolManager_evt_ModifyLiquidity }} ml
                    LEFT JOIN 
                        filtered_swaps s ON ml.evt_block_time > s.evt_block_time AND ml.id = s.id
                    LEFT JOIN 
                        {{ PoolManager_evt_Initialize }} i ON ml.evt_block_time >= i.evt_block_time AND i.{{pair_column_name}} = ml.id
                    {%- if is_incremental() %}
                        WHERE
                            {{ incremental_predicate('ml.evt_block_time') }}
                    {%- endif %}
            )tbl
        WHERE rn = 1
)

If this implementation outputs the same data, we may optimize the query, but probably not.

Copy link
Collaborator

Choose a reason for hiding this comment

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

Original implementation preview with 3893 rows:
https://dune.com/queries/4719491

Copy link
Collaborator

@Hosuke Hosuke Feb 13, 2025

Choose a reason for hiding this comment

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

Modified implementation with 3892 rows (match the original time duration):
https://dune.com/queries/4719556

If modification is acceptable, we may optimize this query a bit.

)tbl
WHERE rn = 1
),
prep_for_calculations AS (
SELECT evt_block_time as block_time
, evt_block_number as block_number
, id
, evt_tx_hash as tx_hash
, evt_index
, salt
, token0
, token1
, LOG(sqrtPriceX96/POWER(2, 96), 10)/LOG(1.0001, 10) as tickCurrent
, tickLower
, tickUpper
, SQRT(POWER(1.0001, tickLower)) as sqrtRatioL
, SQRT(POWER(1.0001, tickUpper)) sqrtRatioU
, sqrtPriceX96/ POWER(2, 96) sqrtPrice
, sqrtPriceX96
, liquidityDelta
FROM get_recent_sqrtPriceX96
),
base_amounts AS (
SELECT
block_time
, block_number
, id
, tx_hash
, evt_index
, salt
, token0
, token1
, CASE WHEN sqrtPrice <= sqrtRatioL THEN liquidityDelta * ((sqrtRatioU - sqrtRatioL)/(sqrtRatioL*sqrtRatioU))
WHEN sqrtPrice >= sqrtRatioU THEN 0
ELSE liquidityDelta * ((sqrtRatioU - sqrtPrice)/(sqrtPrice*sqrtRatioU))
END as amount0
, CASE WHEN sqrtPrice <= sqrtRatioL THEN 0
WHEN sqrtPrice >= sqrtRatioU THEN liquidityDelta*(sqrtRatioU - sqrtRatioL)
ELSE liquidityDelta*(sqrtPrice - sqrtRatioL)
END as amount1
FROM prep_for_calculations pc
)
SELECT
'{{blockchain}}' AS blockchain
, '{{project}}' AS project
, '{{version}}' AS version
, CAST(date_trunc('month', base.block_time) AS date) AS block_month
, CAST(date_trunc('day', base.block_time) AS date) AS block_date
, block_time
, block_number
, id
, tx_hash
, evt_index
, salt
, token0
, token1
, CAST(amount0 AS double) as amount0_raw
, CAST(amount1 AS double) as amount1_raw
FROM base_amounts base

{% endmacro %}
120 changes: 120 additions & 0 deletions dbt_subprojects/dex/macros/models/enrich_dex_liq_with_prices.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,120 @@
{% macro enrich_dex_liq_with_prices(
base_liquidity = null
, tokens_erc20_model = null
)
%}

WITH base_liquidity as (
SELECT
*
IrishLatte19 marked this conversation as resolved.
Show resolved Hide resolved
FROM
{{ base_liquidity }}
{% if is_incremental() %}
WHERE
{{ incremental_predicate('block_time') }}
{% endif %}
)
, tokens_metadata as (
--erc20 tokens
select
blockchain
, contract_address
, symbol
, decimals
from
{{ tokens_erc20_model }}
union all
--native tokens
select
blockchain
, {{var('ETH_ERC20_ADDRESS')}} as contract_address -- 0x00..00
, native_token_symbol as symbol
, 18 as decimals
from {{ source('evms','info') }}
)
, enrichments AS (
SELECT
base.blockchain
, base.project
, base.version
, base.block_month
, base.block_date
, base.block_time
, base.block_number
, base.id
, base.tx_hash
, base.evt_index
, base.salt
, base.token0
, base.token1
, base.amount0_raw
, base.amount1_raw
, base.amount0_raw/pow(10,tk0.decimals) as amount0
, base.amount1_raw/pow(10,tk1.decimals) as amount1
FROM
base_liquidity base
LEFT JOIN
tokens_metadata as tk0 ON tk0.contract_address = base.token0
AND tk0.blockchain = base.blockchain
LEFT JOIN
tokens_metadata as tk1 ON tk1.contract_address = base.token1
AND tk1.blockchain = base.blockchain

)
, enrichment_with_prices AS (
SELECT
en.blockchain
, en.project
, en.version
, en.block_month
, en.block_date
, en.block_time
, en.block_number
, en.id
, en.tx_hash
, en.evt_index
, en.salt
, en.token0
, en.token1
, en.amount0_raw
, en.amount1_raw
, en.amount0
, en.amount1
, en.amount0 * p0.price AS amount0_usd
, en.amount1 * p1.price AS amount1_usd
FROM enrichments en
LEFT JOIN {{ source('prices','usd') }} p0
ON en.token0 = p0.contract_address
AND en.blockchain = p0.blockchain
AND p0.minute = date_trunc('minute', en.block_time)
LEFT JOIN {{ source('prices','usd') }} p1
ON en.token1 = p1.contract_address
AND en.blockchain = p1.blockchain
AND p1.minute = date_trunc('minute', en.block_time)
IrishLatte19 marked this conversation as resolved.
Show resolved Hide resolved
)


SELECT
blockchain
, project
, version
, block_month
, block_date
, block_time
, block_number
, id
, tx_hash
, evt_index
, salt
, token0
, token1
, amount0_raw
, amount1_raw
, amount0
, amount1
, amount0_usd
, amount1_usd
FROM
enrichment_with_prices

{% endmacro %}
109 changes: 109 additions & 0 deletions dbt_subprojects/dex/models/liquidity/_schema.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,109 @@
version: 2

models:
- name: dex_liquidity
meta:
blockchain: ethereum
sector: dex
short_description: The `dex.liquidity` table captures liquidity data on DEXs. This table contains a detailed breakdown of liquidity pmodified per transaction.
contributors: irishLatte19
config:
tags: [ 'dex', 'liquidity']
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- blockchain
- project
- version
- tx_hash
- evt_index
columns:
- &blockchain
name: blockchain
description: "Blockchain on which the liquidity has been provided/ removed"
- &project
name: project
description: "Name of the dex"
- &version
name: version
description: "Version of the DEX protocol/contract"
- &block_month
name: block_month
description: "UTC event block month"
- &block_date
name: block_date
description: "UTC event block date"
- &block_time
name: block_time
description: "UTC event block time"
- &block_number
name: block_number
description: "Block number of the block in which the trade occurred"
- &id
name: id
description: "Pool Address"
- &tx_hash
name: tx_hash
description: "The hash of the transaction"
- &evt_index
name: evt_index
description: "Index of the event in the transaction. Can be used to uniquely identify the order of events within a transaction"
- &salt
name: salt
description: "Salt is used to distinguish positions of the same range on the same pool/ id"
- &token0
name: token0
description: "Address of token0"
- &token1
name: token1
description: "Address of token1"
- &amount0_raw
name: amount0_raw
description: "Liquidity amount of token0 in units"
- &amount1_raw
name: amount1_raw
description: "Liquidity amount of token1 in units"
- &amount0
name: amount0
description: "Liquidity amount of token0 in units (decimal normalized)"
- &amount1
name: amount1
description: "Liquidity amount of token1 in units(decimal normalized)"
- &amount0_usd
name: amount0_usd
description: "Liquidity amount of token0 in USD"
- &amount1_usd
name: amount1_usd
description: "Liquidity amount of token1 in USD"

- name: dex_base_liquidity
meta:
blockchain: ethereum
sector: dex
contributors: irishLatte19
config:
tags: [ 'dex' ]
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- blockchain
- project
- version
- tx_hash
- evt_index
columns:
- *blockchain
- *project
- *version
- *block_month
- *block_date
- *block_time
- *block_number
- *id
- *tx_hash
- *evt_index
- *salt
- *token0
- *token1
- *amount0_raw
- *amount1_raw
52 changes: 52 additions & 0 deletions dbt_subprojects/dex/models/liquidity/dex_base_liquidity.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
{{ config(
schema = 'dex'
, alias = 'base_liquidity'
, partition_by = ['block_month', 'blockchain', 'project']
, materialized = 'incremental'
, file_format = 'delta'
, incremental_strategy = 'merge'
, unique_key = ['blockchain', 'project', 'version', 'tx_hash', 'evt_index']
, incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')]
)
}}

{% set models = [
ref('dex_ethereum_base_liquidity')
] %}

with base_union as (
SELECT *
FROM
(
{% for model in models %}
SELECT
blockchain
, project
, version
, block_month
, block_date
, block_time
, block_number
, id
, tx_hash
, evt_index
, salt
, token0
, token1
, amount0_raw
, amount1_raw
FROM
{{ model }}
{% if is_incremental() %}
WHERE {{ incremental_predicate('block_time') }}
{% endif %}
{% if not loop.last %}
UNION ALL
{% endif %}
{% endfor %}
)
)
select
*
from
base_union
Loading