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

optimism: uniswap pools dex balances #7271

Closed
wants to merge 30 commits into from
Closed
Show file tree
Hide file tree
Changes from 9 commits
Commits
Show all changes
30 commits
Select commit Hold shift + click to select a range
2064ab8
uniswap dex balances
Jason4276 Dec 9, 2024
c6431f9
Merge branch 'main' into op-token
Jason4276 Dec 9, 2024
e194cd5
updated sql file
Jason4276 Dec 9, 2024
80eae5d
Update op_token_balances.sql
Jason4276 Dec 9, 2024
e504d22
updated sql file
Jason4276 Dec 9, 2024
f46df27
Merge branch 'op-token' of https://github.com/LamprosLabsDAO/spellboo…
Jason4276 Dec 9, 2024
678785b
updated files
Jason4276 Dec 11, 2024
cb646db
updated sources file
Jason4276 Dec 12, 2024
eaf15c1
Upadate source
Jason4276 Dec 16, 2024
e63af4b
Update _sources.yml
Jason4276 Dec 17, 2024
c15e263
Upadate source
Jason4276 Dec 18, 2024
e5bec48
Merge remote-tracking branch 'origin/op-token' into op-token
Jason4276 Dec 18, 2024
8583f36
Merge branch 'main' into op-token
Jason4276 Dec 18, 2024
955aa94
Upadate source
Jason4276 Dec 18, 2024
44169d6
Merge remote-tracking branch 'origin/op-token' into op-token
Jason4276 Dec 18, 2024
d6902fe
Upadate sql file
Jason4276 Dec 18, 2024
5ac9413
Upadate sql file
Jason4276 Dec 18, 2024
3bcaf18
Merge branch 'main' into op-token
Jason4276 Dec 20, 2024
47b3005
Upadate sql file
Jason4276 Dec 20, 2024
7f5c0fe
Upadate sql file
Jason4276 Dec 20, 2024
92125ca
Merge branch 'main' into op-token
Jason4276 Dec 24, 2024
c3b201b
Added curve pool dex balances
Jason4276 Dec 31, 2024
2e97dc2
updated curve sql file
Jason4276 Dec 31, 2024
1c2fbde
updated curve sql file
Jason4276 Dec 31, 2024
d8701aa
Merge branch 'main' into op-token
Jason4276 Dec 31, 2024
f8b155d
updated curve sql file
Jason4276 Dec 31, 2024
2929051
Merge branch 'op-token' of https://github.com/LamprosLabsDAO/spellboo…
Jason4276 Dec 31, 2024
a562a82
update files
Jason4276 Jan 1, 2025
e20be39
Update uniswap_pools_optimism_balances.sql
Jason4276 Jan 3, 2025
d482afd
Merge branch 'main' into op-token
Jason4276 Jan 8, 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,17 @@
version: 2

models:
- name: uniswap_pools_optimism_balances
description: "Tracks OP token balances in Uniswap pools on Optimism."
meta:
blockchain: optimism
sector: DEX
project: uniswap
contributors: jason
config:
tags: ['optimism', 'op_token', 'balances', 'uniswap']
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- pool_address
- snapshot_day
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
{{
config(
schema = 'uniswap_pools_optimism',
alias = 'balances',
materialized = 'incremental',
file_format = 'delta',
incremental_strategy = 'merge',
unique_key = ['pool_address', 'snapshot_day'],
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.snapshot_day')]
)
}}

WITH op_pools AS (
SELECT
pool AS pool_address,
token0,
token1,

fee AS fee_tier,
evt_block_time AS creation_time
FROM
{{ source('uniswap_v3_optimism', 'UniswapV3Factory_evt_PoolCreated') }}
WHERE
(token0 = 0x4200000000000000000000000000000000000042
OR token1 = 0x4200000000000000000000000000000000000042)
),
filtered_balances AS (
SELECT
address AS pool_address,
balance AS op_balance,
day AS snapshot_day
FROM
{{ source('tokens_optimism', 'balances_daily') }}
WHERE
token_address = 0x4200000000000000000000000000000000000042
{% if is_incremental() %}
and {{ incremental_predicate('day') }}
{% else %}
and day >= date '2021-11-11' --first pool initiated
{% endif %}
)
SELECT
p.pool_address,
p.token0,
p.token1,
p.fee_tier,
p.creation_time,
COALESCE(b.op_balance, 0) AS op_balance,
COALESCE(b.snapshot_day, CURRENT_DATE) AS snapshot_day
FROM
op_pools p
LEFT JOIN
filtered_balances b ON p.pool_address = b.pool_address
Copy link
Member

Choose a reason for hiding this comment

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

Suggested change
FROM
op_pools p
LEFT JOIN
filtered_balances b ON p.pool_address = b.pool_address
FROM
filtered_balances b
RIGHT JOIN
op_pools p ON p.pool_address = b.pool_address

Copy link
Member

Choose a reason for hiding this comment

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

thank you for the patience and iterating on changes to improve the spell. one last request, can we try flipping the read table and right join pools, since balances is larger table? just curious to see impact on run time.

Copy link
Contributor Author

Choose a reason for hiding this comment

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

Thanks for the suggestion! I've updated the query to use a RIGHT JOIN with filtered_balances as the read table and op_pools on the right. I'll test the runtime and see if it improves performance.

2 changes: 2 additions & 0 deletions sources/_sector/dex/trades/optimism/_sources.yml
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,8 @@ version: 2

sources:
- name: uniswap_v3_optimism
tables:
- name: UniswapV3Factory_evt_PoolCreated
jeff-dude marked this conversation as resolved.
Show resolved Hide resolved
- name: sushi_optimism
tables:
- name: ConstantProductPool_evt_Swap
Expand Down
1 change: 1 addition & 0 deletions sources/_subprojects_outputs/tokens/balances.yml
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ sources:
tables:
- name: balances_daily_agg
- name: balances_daily_agg_base
- name: balances_daily
- name: tokens_polygon
tables:
- name: balances_daily_agg
Expand Down
Loading