Skip to content

Commit

Permalink
Migrate balancer_v2_trades to DuneSQL
Browse files Browse the repository at this point in the history
  • Loading branch information
thetroyharris committed Aug 15, 2023
1 parent 8e82d44 commit 83ca534
Show file tree
Hide file tree
Showing 6 changed files with 165 additions and 169 deletions.
85 changes: 42 additions & 43 deletions models/balancer/arbitrum/balancer_v2_arbitrum_trades.sql
Original file line number Diff line number Diff line change
@@ -1,36 +1,37 @@
{{ config(
schema = 'balancer_v2_arbitrum',
schema = 'balancer_v2_ethereum',
tags = ['dunesql'],
alias = alias('trades'),
partition_by = ['block_date'],
materialized = 'incremental',
file_format = 'delta',
incremental_strategy = 'merge',
unique_key = ['block_date', 'blockchain', 'project', 'version', 'tx_hash', 'evt_index', 'trace_address'],
post_hook = '{{ expose_spells(\'["arbitrum"]\',
post_hook = '{{ expose_spells(\'["ethereum"]\',
"project",
"balancer_v2",
\'["mendesfabio", "jacektrocinski", "thetroyharris"]\') }}'
)
}}

{% set project_start_date = '2021-08-27' %}
{% set project_start_date = '2021-08-26' %}

WITH
WITH
swap_fees AS (
SELECT
swaps.poolId,
swaps.evt_tx_hash,
swaps.evt_index,
swaps.evt_block_number,
SUBSTRING(CAST(swaps.poolId AS varchar(66)), 1, 42) AS contract_address,
bytearray_substring(swaps.poolId, 1, 20) AS contract_address,
fees.swap_fee_percentage,
ROW_NUMBER() OVER (PARTITION BY poolId, evt_tx_hash, evt_index ORDER BY block_number DESC, index DESC) AS rn
FROM {{ source ('balancer_v2_arbitrum', 'Vault_evt_Swap') }} swaps
LEFT JOIN {{ ref('balancer_v2_arbitrum_pools_fees') }} fees
ON CAST(fees.contract_address AS varchar(66)) = substring(CAST(swaps.poolId AS varchar(66)), 1, 42)
AND ARRAY(fees.block_number) || ARRAY(fees.index) < ARRAY(swaps.evt_block_number) || ARRAY(swaps.evt_index)
FROM {{ source ('balancer_v2_ethereum', 'Vault_evt_Swap') }} swaps
LEFT JOIN {{ ref('balancer_v2_ethereum_pools_fees') }} fees
ON fees.contract_address = bytearray_substring(swaps.poolId, 1, 20)
AND ARRAY[fees.block_number] || ARRAY[fees.index] < ARRAY[swaps.evt_block_number] || ARRAY[swaps.evt_index]
{% if is_incremental() %}
WHERE swaps.evt_block_time >= date_trunc('day', NOW() - interval '1 week')
WHERE swaps.evt_block_time >= date_trunc('day', NOW() - interval '7' day)
{% endif %}
),
dexs AS (
Expand All @@ -52,7 +53,7 @@ WITH
swap.evt_index
FROM
swap_fees
INNER JOIN {{ source ('balancer_v2_arbitrum', 'Vault_evt_Swap') }} swap
INNER JOIN {{ source ('balancer_v2_ethereum', 'Vault_evt_Swap') }} swap
ON swap.evt_block_number = swap_fees.evt_block_number
AND swap.evt_tx_hash = swap_fees.evt_tx_hash
AND swap.evt_index = swap_fees.evt_index
Expand All @@ -71,14 +72,14 @@ WITH
MAX(bpt_prices.hour) AS bpa_max_block_time
FROM
dexs
LEFT JOIN {{ ref('balancer_v2_arbitrum_bpt_prices') }} bpt_prices
ON bpt_prices.contract_address = dexs.token_bought_address
LEFT JOIN {{ ref('balancer_v2_ethereum_bpt_prices') }} bpt_prices
ON bpt_prices.contract_address = CAST(dexs.token_bought_address AS VARCHAR)
AND bpt_prices.hour <= dexs.block_time
{% if not is_incremental() %}
AND bpt_prices.hour >= '{{ project_start_date }}'
AND bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
GROUP BY 1, 2, 3, 4, 5
),
Expand All @@ -92,20 +93,20 @@ WITH
MAX(bpt_prices.hour) AS bpb_max_block_time
FROM
dexs
LEFT JOIN {{ ref('balancer_v2_arbitrum_bpt_prices') }} bpt_prices
ON bpt_prices.contract_address = dexs.token_sold_address
LEFT JOIN {{ ref('balancer_v2_ethereum_bpt_prices') }} bpt_prices
ON bpt_prices.contract_address = CAST(dexs.token_sold_address AS VARCHAR)
AND bpt_prices.hour <= dexs.block_time
{% if not is_incremental() %}
AND bpt_prices.hour >= '{{ project_start_date }}'
AND bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
GROUP BY 1, 2, 3, 4, 5
)

SELECT
'arbitrum' AS blockchain,
'ethereum' AS blockchain,
'balancer' AS project,
'2' AS version,
DATE_TRUNC('DAY', dexs.block_time) AS block_date,
Expand All @@ -119,10 +120,8 @@ SELECT
END AS token_pair,
dexs.token_bought_amount_raw / POWER(10, COALESCE(erc20a.decimals, 18)) AS token_bought_amount,
dexs.token_sold_amount_raw / POWER(10, COALESCE(erc20b.decimals, 18)) AS token_sold_amount,
CAST(dexs.token_bought_amount_raw AS DECIMAL(38,0)) AS token_bought_amount_raw,
CAST(dexs.token_sold_amount_raw AS DECIMAL(38,0)) AS token_sold_amount_raw,
-- dexs.token_bought_amount_raw,
-- dexs.token_sold_amount_raw,
CAST(dexs.token_bought_amount_raw AS UINT256) AS token_bought_amount_raw,
CAST(dexs.token_sold_amount_raw AS UINT256) AS token_sold_amount_raw,
COALESCE(
dexs.amount_usd,
dexs.token_bought_amount_raw / POWER(10, p_bought.decimals) * p_bought.price,
Expand All @@ -132,75 +131,75 @@ SELECT
) AS amount_usd,
dexs.token_bought_address,
dexs.token_sold_address,
COALESCE(dexs.taker, tx.`from`) AS taker,
dexs.taker AS taker,
dexs.maker,
dexs.project_contract_address,
dexs.poolId,
dexs.swap_fee,
dexs.tx_hash,
tx.`from` AS tx_from,
tx."from" AS tx_from,
tx.to AS tx_to,
dexs.trace_address,
dexs.evt_index
FROM
dexs
INNER JOIN {{ source ('arbitrum', 'transactions') }} tx
INNER JOIN {{ source ('ethereum', 'transactions') }} tx
ON tx.hash = dexs.tx_hash
{% if not is_incremental() %}
AND tx.block_time >= '{{ project_start_date }}'
AND tx.block_time >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND tx.block_time >= DATE_TRUNC("day", NOW() - interval '1 week')
AND tx.block_time >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
LEFT JOIN {{ ref ('tokens_erc20') }} erc20a
ON erc20a.contract_address = dexs.token_bought_address
AND erc20a.blockchain = 'arbitrum'
AND erc20a.blockchain = 'ethereum'
LEFT JOIN {{ ref ('tokens_erc20') }} erc20b
ON erc20b.contract_address = dexs.token_sold_address
AND erc20b.blockchain = 'arbitrum'
AND erc20b.blockchain = 'ethereum'
LEFT JOIN {{ source ('prices', 'usd') }} p_bought
ON p_bought.minute = DATE_TRUNC('minute', dexs.block_time)
AND p_bought.contract_address = dexs.token_bought_address
AND p_bought.blockchain = 'arbitrum'
AND p_bought.blockchain = 'ethereum'
{% if not is_incremental() %}
AND p_bought.minute >= '{{ project_start_date }}'
AND p_bought.minute >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND p_bought.minute >= DATE_TRUNC("day", NOW() - interval '1 week')
AND p_bought.minute >= DATE_TRUNC("day", NOW() - interval '7' day)
{% 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 = 'arbitrum'
AND p_sold.blockchain = 'ethereum'
{% if not is_incremental() %}
AND p_sold.minute >= '{{ project_start_date }}'
AND p_sold.minute >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND p_sold.minute >= DATE_TRUNC("day", NOW() - interval '1 week')
AND p_sold.minute >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
INNER JOIN bpa
ON bpa.evt_block_number = dexs.evt_block_number
AND bpa.tx_hash = dexs.tx_hash
AND bpa.evt_index = dexs.evt_index
LEFT JOIN {{ ref('balancer_v2_arbitrum_bpt_prices') }} bpa_bpt_prices
LEFT JOIN {{ ref('balancer_v2_ethereum_bpt_prices') }} bpa_bpt_prices
ON bpa_bpt_prices.contract_address = bpa.contract_address
AND bpa_bpt_prices.hour = bpa.bpa_max_block_time
{% if not is_incremental() %}
AND bpa_bpt_prices.hour >= '{{ project_start_date }}'
AND bpa_bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
INNER JOIN bpb
ON bpb.evt_block_number = dexs.evt_block_number
AND bpb.tx_hash = dexs.tx_hash
AND bpb.evt_index = dexs.evt_index
LEFT JOIN {{ ref('balancer_v2_arbitrum_bpt_prices') }} bpb_bpt_prices
LEFT JOIN {{ ref('balancer_v2_ethereum_bpt_prices') }} bpb_bpt_prices
ON bpb_bpt_prices.contract_address = bpb.contract_address
AND bpb_bpt_prices.hour = bpb.bpb_max_block_time
{% if not is_incremental() %}
AND bpa_bpt_prices.hour >= '{{ project_start_date }}'
AND bpa_bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
2 changes: 1 addition & 1 deletion models/balancer/ethereum/balancer_ethereum_trades.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@
}}

{% set balancer_models = [
ref('balancer_v1_ethereum_trades'),
--ref('balancer_v1_ethereum_trades'),
ref('balancer_v2_ethereum_trades')
] %}

Expand Down
51 changes: 25 additions & 26 deletions models/balancer/ethereum/balancer_v2_ethereum_trades.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
{{ config(
schema = 'balancer_v2_ethereum',
tags = ['dunesql'],
alias = alias('trades'),
partition_by = ['block_date'],
materialized = 'incremental',
Expand All @@ -22,15 +23,15 @@ WITH
swaps.evt_tx_hash,
swaps.evt_index,
swaps.evt_block_number,
SUBSTRING(CAST(swaps.poolId AS varchar(66)), 1, 42) AS contract_address,
bytearray_substring(swaps.poolId, 1, 20) AS contract_address,
fees.swap_fee_percentage,
ROW_NUMBER() OVER (PARTITION BY poolId, evt_tx_hash, evt_index ORDER BY block_number DESC, index DESC) AS rn
FROM {{ source ('balancer_v2_ethereum', 'Vault_evt_Swap') }} swaps
LEFT JOIN {{ ref('balancer_v2_ethereum_pools_fees') }} fees
ON CAST(fees.contract_address AS varchar(66)) = substring(CAST(swaps.poolId AS varchar(66)), 1, 42)
AND ARRAY(fees.block_number) || ARRAY(fees.index) < ARRAY(swaps.evt_block_number) || ARRAY(swaps.evt_index)
ON fees.contract_address = bytearray_substring(swaps.poolId, 1, 20)
AND ARRAY[fees.block_number] || ARRAY[fees.index] < ARRAY[swaps.evt_block_number] || ARRAY[swaps.evt_index]
{% if is_incremental() %}
WHERE swaps.evt_block_time >= date_trunc('day', NOW() - interval '1 week')
WHERE swaps.evt_block_time >= date_trunc('day', NOW() - interval '7' day)
{% endif %}
),
dexs AS (
Expand Down Expand Up @@ -72,13 +73,13 @@ WITH
FROM
dexs
LEFT JOIN {{ ref('balancer_v2_ethereum_bpt_prices') }} bpt_prices
ON bpt_prices.contract_address = dexs.token_bought_address
ON bpt_prices.contract_address = CAST(dexs.token_bought_address AS VARCHAR)
AND bpt_prices.hour <= dexs.block_time
{% if not is_incremental() %}
AND bpt_prices.hour >= '{{ project_start_date }}'
AND bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
GROUP BY 1, 2, 3, 4, 5
),
Expand All @@ -93,13 +94,13 @@ WITH
FROM
dexs
LEFT JOIN {{ ref('balancer_v2_ethereum_bpt_prices') }} bpt_prices
ON bpt_prices.contract_address = dexs.token_sold_address
ON bpt_prices.contract_address = CAST(dexs.token_sold_address AS VARCHAR)
AND bpt_prices.hour <= dexs.block_time
{% if not is_incremental() %}
AND bpt_prices.hour >= '{{ project_start_date }}'
AND bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
GROUP BY 1, 2, 3, 4, 5
)
Expand All @@ -119,10 +120,8 @@ SELECT
END AS token_pair,
dexs.token_bought_amount_raw / POWER(10, COALESCE(erc20a.decimals, 18)) AS token_bought_amount,
dexs.token_sold_amount_raw / POWER(10, COALESCE(erc20b.decimals, 18)) AS token_sold_amount,
CAST(dexs.token_bought_amount_raw AS DECIMAL(38,0)) AS token_bought_amount_raw,
CAST(dexs.token_sold_amount_raw AS DECIMAL(38,0)) AS token_sold_amount_raw,
-- dexs.token_bought_amount_raw,
-- dexs.token_sold_amount_raw,
CAST(dexs.token_bought_amount_raw AS UINT256) AS token_bought_amount_raw,
CAST(dexs.token_sold_amount_raw AS UINT256) AS token_sold_amount_raw,
COALESCE(
dexs.amount_usd,
dexs.token_bought_amount_raw / POWER(10, p_bought.decimals) * p_bought.price,
Expand All @@ -132,13 +131,13 @@ SELECT
) AS amount_usd,
dexs.token_bought_address,
dexs.token_sold_address,
COALESCE(dexs.taker, tx.`from`) AS taker,
dexs.taker AS taker,
dexs.maker,
dexs.project_contract_address,
dexs.poolId,
dexs.swap_fee,
dexs.tx_hash,
tx.`from` AS tx_from,
tx."from" AS tx_from,
tx.to AS tx_to,
dexs.trace_address,
dexs.evt_index
Expand All @@ -147,10 +146,10 @@ FROM
INNER JOIN {{ source ('ethereum', 'transactions') }} tx
ON tx.hash = dexs.tx_hash
{% if not is_incremental() %}
AND tx.block_time >= '{{ project_start_date }}'
AND tx.block_time >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND tx.block_time >= DATE_TRUNC("day", NOW() - interval '1 week')
AND tx.block_time >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
LEFT JOIN {{ ref ('tokens_erc20') }} erc20a
ON erc20a.contract_address = dexs.token_bought_address
Expand All @@ -163,20 +162,20 @@ FROM
AND p_bought.contract_address = dexs.token_bought_address
AND p_bought.blockchain = 'ethereum'
{% if not is_incremental() %}
AND p_bought.minute >= '{{ project_start_date }}'
AND p_bought.minute >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND p_bought.minute >= DATE_TRUNC("day", NOW() - interval '1 week')
AND p_bought.minute >= DATE_TRUNC("day", NOW() - interval '7' day)
{% 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 = 'ethereum'
{% if not is_incremental() %}
AND p_sold.minute >= '{{ project_start_date }}'
AND p_sold.minute >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND p_sold.minute >= DATE_TRUNC("day", NOW() - interval '1 week')
AND p_sold.minute >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
INNER JOIN bpa
ON bpa.evt_block_number = dexs.evt_block_number
Expand All @@ -186,10 +185,10 @@ FROM
ON bpa_bpt_prices.contract_address = bpa.contract_address
AND bpa_bpt_prices.hour = bpa.bpa_max_block_time
{% if not is_incremental() %}
AND bpa_bpt_prices.hour >= '{{ project_start_date }}'
AND bpa_bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}
INNER JOIN bpb
ON bpb.evt_block_number = dexs.evt_block_number
Expand All @@ -199,8 +198,8 @@ FROM
ON bpb_bpt_prices.contract_address = bpb.contract_address
AND bpb_bpt_prices.hour = bpb.bpb_max_block_time
{% if not is_incremental() %}
AND bpa_bpt_prices.hour >= '{{ project_start_date }}'
AND bpa_bpt_prices.hour >= CAST('{{ project_start_date }}' AS TIMESTAMP)
{% endif %}
{% if is_incremental() %}
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '1 week')
AND bpa_bpt_prices.hour >= DATE_TRUNC("day", NOW() - interval '7' day)
{% endif %}

0 comments on commit 83ca534

Please sign in to comment.