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

Added odos_v2 optimism dex #5267

Merged
merged 5 commits into from
Feb 2, 2024
Merged
Show file tree
Hide file tree
Changes from 1 commit
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
91 changes: 88 additions & 3 deletions models/odos/optimism/odos_optimism_schema.yml
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
version: 2

models:
- name: odos_optimism_trades
- name: odos_v1_optimism_trades
meta:
blockchain: optimism
sector: dex
Expand All @@ -10,7 +10,7 @@ models:
config:
tags: ['optimism','trades', 'odos','dex']
description: >
odos dex trades on optimism
A table containing all trades of odos v1 on optimism
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
Expand Down Expand Up @@ -96,4 +96,89 @@ models:
description: ""
- &trace_address
name: trace_address
description: ""
description: ""

- name: odos_v2_optimism_trades
meta:
blockchain: optimism
sector: dex
project: odos
contributors: ARDev097
config:
tags: ['optimism','trades', 'odos','dex']
description: >
A table containing all trades of odos v2 on optimism
tests:
jeff-dude marked this conversation as resolved.
Show resolved Hide resolved
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- block_date
- blockchain
- project
- version
- tx_hash
- evt_index
- check_dex_aggregator_seed:
blockchain: optimism
project: odos
version: 2
columns:
- *blockchain
- *project
- *version
- *block_month
- *block_date
- *block_time
- *token_bought_symbol
- *token_sold_symbol
- *token_pair
- *token_bought_amount
- *token_sold_amount
- *token_bought_amount_raw
- *token_sold_amount_raw
- *amount_usd
- *token_bought_address
- *token_sold_address
- *taker
- *maker
- *project_contract_address
- *tx_hash
- *tx_from
- *tx_to
- *evt_index
- *trace_address

- name: odos_optimism_trades
meta:
blockchain: optimism
sector: dex
project: odos
contributors: ARDev097
config:
tags: ['optimism','trades', 'odos','dex']
description: >
A table containing all trades of odos on optimism.
columns:
- *blockchain
- *project
- *version
- *block_month
- *block_date
- *block_time
- *token_bought_symbol
- *token_sold_symbol
- *token_pair
- *token_bought_amount
- *token_sold_amount
- *token_bought_amount_raw
- *token_sold_amount_raw
- *amount_usd
- *token_bought_address
- *token_sold_address
- *taker
- *maker
- *project_contract_address
- *tx_hash
- *tx_from
- *tx_to
- *evt_index
- *trace_address
139 changes: 41 additions & 98 deletions models/odos/optimism/odos_optimism_trades.sql
Original file line number Diff line number Diff line change
@@ -1,103 +1,46 @@
{{ config(
schema = 'odos_optimism'
,alias = 'trades'
,materialized = 'incremental'
,file_format = 'delta'
,incremental_strategy = 'merge'
,unique_key = ['tx_hash', 'evt_index']
,incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')]
)
schema = 'odos_optimism'
, alias = 'trades'
)
}}

{% set project_start_date = '2022-10-06' %}
{% set odos_models = [
ref('odos_v1_optimism_trades')
, ref('odos_v2_optimism_trades')
] %}

WITH
dexs as (
SELECT
evt_block_time as block_time,
evt_block_number as block_number,
json_extract_scalar(outputs[1], '$.receiver') AS taker,
CAST(NULL as VARBINARY) as maker,
amountsIn[1] as token_sold_amount_raw,
amountsOut[1] as token_bought_amount_raw,
CAST(NULL as double) as amount_usd,
tokensIn[1] as token_sold_address,
json_extract_scalar(outputs[1], '$.tokenAddress') AS token_bought_address,
contract_address as project_contract_address,
evt_tx_hash as tx_hash,
evt_index,
array[-1] as trace_address
FROM
{{ source('odos_optimism', 'OdosRouter_evt_Swapped') }}
{% if is_incremental() %}
WHERE {{incremental_predicate('evt_block_time')}}
{% else %}
WHERE evt_block_time >= TIMESTAMP '{{project_start_date}}'
{% endif %}
)

SELECT
'optimism' AS blockchain,
'odos' AS project,
'1' AS version,
TRY_CAST(date_trunc('DAY', dexs.block_time) AS date) AS block_date,
TRY_CAST(date_trunc('MONTH', dexs.block_time) AS date) AS block_month,
dexs.block_time,
erc20a.symbol AS token_bought_symbol,
erc20b.symbol AS token_sold_symbol,
CASE
WHEN lower(erc20a.symbol) > lower(erc20b.symbol)
THEN concat(erc20b.symbol, '-', erc20a.symbol)
ELSE concat(erc20a.symbol, '-', erc20b.symbol)
END AS token_pair,
dexs.token_bought_amount_raw / power(10, erc20a.decimals) AS token_bought_amount,
dexs.token_sold_amount_raw / power(10, erc20b.decimals) AS token_sold_amount,
dexs.token_bought_amount_raw AS token_bought_amount_raw,
dexs.token_sold_amount_raw AS token_sold_amount_raw,
COALESCE(
dexs.amount_usd,
(dexs.token_bought_amount_raw / power(10, erc20a.decimals)) * p_bought.price,
(dexs.token_sold_amount_raw / power(10, erc20b.decimals)) * p_sold.price
) AS amount_usd,
CAST(dexs.token_bought_address AS varbinary) AS token_bought_address,
dexs.token_sold_address,
CAST(dexs.taker AS varbinary) AS taker,
dexs.maker,
dexs.project_contract_address,
dexs.tx_hash,
tx."from" AS tx_from,
tx.to AS tx_to,
dexs.evt_index,
dexs.trace_address
FROM dexs
INNER JOIN {{ source('optimism', 'transactions') }} tx
ON dexs.tx_hash = tx.hash
{% if not is_incremental() %}
AND tx.block_time >= DATE '{{project_start_date}}'
{% else %}
AND {{ incremental_predicate('tx.block_time') }}
{% endif %}
LEFT JOIN {{ source('tokens', 'erc20') }} erc20a
ON CAST(erc20a.contract_address AS varchar) = dexs.token_bought_address
AND erc20a.blockchain = 'optimism'
LEFT JOIN {{ source('tokens', 'erc20') }} erc20b
ON erc20b.contract_address = dexs.token_sold_address
AND erc20b.blockchain = 'optimism'
LEFT JOIN {{ source('prices', 'usd') }} p_bought
ON p_bought.minute = date_trunc('minute', dexs.block_time)
AND CAST(p_bought.contract_address AS varchar) = dexs.token_bought_address
AND p_bought.blockchain = 'optimism'
{% if not is_incremental() %}
AND p_bought.minute >= DATE '{{project_start_date}}'
{% else %}
AND {{ incremental_predicate('p_bought.minute') }}
{% endif %}
LEFT JOIN {{ source('prices', 'usd') }} p_sold
ON p_sold.minute = date_trunc('minute', dexs.block_time)
AND p_sold.contract_address = dexs.token_sold_address
AND p_sold.blockchain = 'optimism'
{% if not is_incremental() %}
AND p_sold.minute >= DATE '{{project_start_date}}'
{% else %}
AND {{ incremental_predicate('p_sold.minute') }}
{% endif %}
SELECT *
FROM (
{% for dex_model in odos_models %}
SELECT
blockchain,
project,
version,
block_month,
block_date,
block_time,
token_bought_symbol,
token_sold_symbol,
token_pair,
token_bought_amount,
token_sold_amount,
token_bought_amount_raw,
token_sold_amount_raw,
amount_usd,
token_bought_address,
token_sold_address,
taker,
maker,
project_contract_address,
tx_hash,
tx_from,
tx_to,
evt_index,
trace_address
FROM {{ dex_model }}
{% if not loop.last %}
UNION ALL
{% endif %}
{% endfor %}
)
103 changes: 103 additions & 0 deletions models/odos/optimism/odos_v1_optimism_trades.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,103 @@
{{ config(
schema = 'odos_v1_optimism'
,alias = 'trades'
,materialized = 'incremental'
,file_format = 'delta'
,incremental_strategy = 'merge'
,unique_key = ['tx_hash', 'evt_index']
,incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_time')]
)
}}

{% set project_start_date = '2022-10-06' %}

WITH
dexs as (
SELECT
evt_block_time as block_time,
evt_block_number as block_number,
json_extract_scalar(outputs[1], '$.receiver') AS taker,
CAST(NULL as VARBINARY) as maker,
amountsIn[1] as token_sold_amount_raw,
amountsOut[1] as token_bought_amount_raw,
CAST(NULL as double) as amount_usd,
tokensIn[1] as token_sold_address,
json_extract_scalar(outputs[1], '$.tokenAddress') AS token_bought_address,
contract_address as project_contract_address,
evt_tx_hash as tx_hash,
evt_index,
array[-1] as trace_address
FROM
{{ source('odos_optimism', 'OdosRouter_evt_Swapped') }}
{% if is_incremental() %}
WHERE {{incremental_predicate('evt_block_time')}}
{% else %}
WHERE evt_block_time >= TIMESTAMP '{{project_start_date}}'
{% endif %}
)

SELECT
'optimism' AS blockchain,
'odos' AS project,
'1' AS version,
TRY_CAST(date_trunc('DAY', dexs.block_time) AS date) AS block_date,
TRY_CAST(date_trunc('MONTH', dexs.block_time) AS date) AS block_month,
dexs.block_time,
erc20a.symbol AS token_bought_symbol,
erc20b.symbol AS token_sold_symbol,
CASE
WHEN lower(erc20a.symbol) > lower(erc20b.symbol)
THEN concat(erc20b.symbol, '-', erc20a.symbol)
ELSE concat(erc20a.symbol, '-', erc20b.symbol)
END AS token_pair,
dexs.token_bought_amount_raw / power(10, erc20a.decimals) AS token_bought_amount,
dexs.token_sold_amount_raw / power(10, erc20b.decimals) AS token_sold_amount,
dexs.token_bought_amount_raw AS token_bought_amount_raw,
dexs.token_sold_amount_raw AS token_sold_amount_raw,
COALESCE(
dexs.amount_usd,
(dexs.token_bought_amount_raw / power(10, erc20a.decimals)) * p_bought.price,
(dexs.token_sold_amount_raw / power(10, erc20b.decimals)) * p_sold.price
) AS amount_usd,
CAST(dexs.token_bought_address AS varbinary) AS token_bought_address,
dexs.token_sold_address,
CAST(dexs.taker AS varbinary) AS taker,
dexs.maker,
dexs.project_contract_address,
dexs.tx_hash,
tx."from" AS tx_from,
tx.to AS tx_to,
dexs.evt_index,
dexs.trace_address
FROM dexs
INNER JOIN {{ source('optimism', 'transactions') }} tx
ON dexs.tx_hash = tx.hash
{% if not is_incremental() %}
AND tx.block_time >= DATE '{{project_start_date}}'
{% else %}
AND {{ incremental_predicate('tx.block_time') }}
{% endif %}
LEFT JOIN {{ source('tokens', 'erc20') }} erc20a
ON CAST(erc20a.contract_address AS varchar) = dexs.token_bought_address
AND erc20a.blockchain = 'optimism'
LEFT JOIN {{ source('tokens', 'erc20') }} erc20b
ON erc20b.contract_address = dexs.token_sold_address
AND erc20b.blockchain = 'optimism'
LEFT JOIN {{ source('prices', 'usd') }} p_bought
ON p_bought.minute = date_trunc('minute', dexs.block_time)
AND CAST(p_bought.contract_address AS varchar) = dexs.token_bought_address
AND p_bought.blockchain = 'optimism'
{% if not is_incremental() %}
AND p_bought.minute >= DATE '{{project_start_date}}'
{% else %}
AND {{ incremental_predicate('p_bought.minute') }}
{% endif %}
LEFT JOIN {{ source('prices', 'usd') }} p_sold
ON p_sold.minute = date_trunc('minute', dexs.block_time)
AND p_sold.contract_address = dexs.token_sold_address
AND p_sold.blockchain = 'optimism'
{% if not is_incremental() %}
AND p_sold.minute >= DATE '{{project_start_date}}'
{% else %}
AND {{ incremental_predicate('p_sold.minute') }}
{% endif %}
Loading
Loading