mirror of
https://github.com/FlipsideCrypto/base-models.git
synced 2026-02-06 14:26:54 +00:00
1312 lines
29 KiB
SQL
1312 lines
29 KiB
SQL
-- depends_on: {{ ref('silver__complete_token_prices') }}
|
|
-- depends_on: {{ ref('price__ez_asset_metadata') }}
|
|
{{ config(
|
|
materialized = 'incremental',
|
|
incremental_strategy = 'delete+insert',
|
|
unique_key = ['block_number','platform','version'],
|
|
cluster_by = ['block_timestamp::DATE','platform'],
|
|
post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(tx_hash, origin_function_signature, origin_from_address, origin_to_address, contract_address, pool_name, event_name, sender, tx_to, token_in, token_out, symbol_in, symbol_out), SUBSTRING(origin_function_signature, pool_name, event_name, sender, tx_to, token_in, token_out, symbol_in, symbol_out)",
|
|
tags = ['silver_dex','defi','dex','curated','heal']
|
|
) }}
|
|
|
|
WITH univ2 AS (
|
|
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'uniswap' as protocol,
|
|
'v2' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__univ2_swaps') }}
|
|
|
|
{% if is_incremental() and 'univ2' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
alienbase AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'alienbase' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__alienbase_swaps') }}
|
|
|
|
{% if is_incremental() and 'alienbase' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
maverick AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'maverick' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__maverick_swaps') }}
|
|
|
|
{% if is_incremental() and 'maverick' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
maverick_v2 AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'maverick' as protocol,
|
|
'v2' AS version,
|
|
_log_id,
|
|
modified_timestamp AS _inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__maverick_v2_swaps') }}
|
|
|
|
{% if is_incremental() and 'maverick_v2' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
woofi AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'woofi' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__woofi_swaps') }}
|
|
|
|
{% if is_incremental() and 'woofi' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
balancer AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'balancer' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__balancer_swaps') }}
|
|
|
|
{% if is_incremental() and 'balancer' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
baseswap AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'baseswap' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__baseswap_swaps') }}
|
|
|
|
{% if is_incremental() and 'baseswap' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
baseswap_basex AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
pool_address AS contract_address,
|
|
event_name,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_in_unadj,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_out_unadj,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_in,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_out,
|
|
sender,
|
|
recipient AS tx_to,
|
|
event_index,
|
|
platform,
|
|
'baseswap' as protocol,
|
|
'v3' AS version,
|
|
_log_id,
|
|
modified_timestamp AS _inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__baseswap_basex_swaps') }}
|
|
|
|
{% if is_incremental() and 'baseswap_basex' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
swapbased AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'swapbased' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__swapbased_swaps') }}
|
|
|
|
{% if is_incremental() and 'swapbased' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
aerodrome AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'aerodrome' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__aerodrome_swaps') }}
|
|
|
|
{% if is_incremental() and 'aerodrome' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
voodoo AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'voodoo' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__voodoo_swaps') }}
|
|
|
|
{% if is_incremental() and 'voodoo' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
curve AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
tokens_sold AS amount_in_unadj,
|
|
tokens_bought AS amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'curve' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__curve_swaps') }}
|
|
|
|
{% if is_incremental() and 'curve' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
sushi AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
pool_address AS contract_address,
|
|
'Swap' AS event_name,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_in_unadj,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_out_unadj,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_in,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_out,
|
|
sender,
|
|
recipient AS tx_to,
|
|
event_index,
|
|
'sushiswap' AS platform,
|
|
'sushiswap' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__sushi_swaps') }}
|
|
|
|
{% if is_incremental() and 'sushi' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
dackie AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
pool_address AS contract_address,
|
|
'Swap' AS event_name,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_in_unadj,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_out_unadj,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_in,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_out,
|
|
sender,
|
|
recipient AS tx_to,
|
|
event_index,
|
|
'dackieswap' AS platform,
|
|
'dackieswap' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__dackie_swaps') }}
|
|
|
|
{% if is_incremental() and 'dackie' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
univ3 AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
pool_address AS contract_address,
|
|
'Swap' AS event_name,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_in_unadj,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_out_unadj,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_in,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_out,
|
|
sender,
|
|
recipient AS tx_to,
|
|
event_index,
|
|
'uniswap-v3' AS platform,
|
|
'uniswap' as protocol,
|
|
'v3' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__univ3_swaps') }}
|
|
|
|
{% if is_incremental() and 'univ3' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
aerodrome_slipstream AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
pool_address AS contract_address,
|
|
'Swap' AS event_name,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_in_unadj,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN ABS(amount0_unadj)
|
|
ELSE ABS(amount1_unadj)
|
|
END AS amount_out_unadj,
|
|
CASE
|
|
WHEN amount0_unadj > 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_in,
|
|
CASE
|
|
WHEN amount0_unadj < 0 THEN token0_address
|
|
ELSE token1_address
|
|
END AS token_out,
|
|
sender,
|
|
recipient AS tx_to,
|
|
event_index,
|
|
'aerodrome-slipstream' AS platform,
|
|
'aerodrome' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__aerodrome_slipstream_swaps') }}
|
|
|
|
{% if is_incremental() and 'aerodrome-slipstream' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
pancakeswap_v3 AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'pancakeswap' as protocol,
|
|
'v3' AS version,
|
|
_log_id,
|
|
modified_timestamp AS _inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__pancakeswap_v3_swaps') }}
|
|
|
|
{% if is_incremental() and 'pancakeswap_v3' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
dexalot AS (
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_out_unadj,
|
|
token_in,
|
|
token_out,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
'dexalot' as protocol,
|
|
'v1' AS version,
|
|
_log_id,
|
|
modified_timestamp AS _inserted_timestamp
|
|
FROM
|
|
{{ ref('silver_dex__dexalot_swaps') }}
|
|
|
|
{% if is_incremental() and 'dexalot' not in var('HEAL_MODELS') %}
|
|
WHERE
|
|
_inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
all_dex AS (
|
|
SELECT
|
|
*
|
|
FROM
|
|
swapbased
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
univ2
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
alienbase
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
aerodrome
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
baseswap
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
baseswap_basex
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
woofi
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
maverick
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
maverick_v2
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
balancer
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
voodoo
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
curve
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
univ3
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
aerodrome_slipstream
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
sushi
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
dackie
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
pancakeswap_v3
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
dexalot
|
|
),
|
|
complete_dex_swaps AS (
|
|
SELECT
|
|
s.block_number,
|
|
s.block_timestamp,
|
|
s.tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
s.contract_address,
|
|
event_name,
|
|
token_in,
|
|
p1.is_verified AS token_in_is_verified,
|
|
c1.token_decimals AS decimals_in,
|
|
c1.token_symbol AS symbol_in,
|
|
amount_in_unadj,
|
|
CASE
|
|
WHEN decimals_in IS NULL THEN amount_in_unadj
|
|
ELSE (amount_in_unadj / pow(10, decimals_in))
|
|
END AS amount_in,
|
|
CASE
|
|
WHEN decimals_in IS NOT NULL THEN amount_in * p1.price
|
|
ELSE NULL
|
|
END AS amount_in_usd,
|
|
token_out,
|
|
p2.is_verified AS token_out_is_verified,
|
|
c2.token_decimals AS decimals_out,
|
|
c2.token_symbol AS symbol_out,
|
|
amount_out_unadj,
|
|
CASE
|
|
WHEN decimals_out IS NULL THEN amount_out_unadj
|
|
ELSE (amount_out_unadj / pow(10, decimals_out))
|
|
END AS amount_out,
|
|
CASE
|
|
WHEN decimals_out IS NOT NULL THEN amount_out * p2.price
|
|
ELSE NULL
|
|
END AS amount_out_usd,
|
|
CASE
|
|
WHEN lp.pool_name IS NULL THEN CONCAT(
|
|
LEAST(
|
|
COALESCE(
|
|
symbol_in,
|
|
CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42))
|
|
),
|
|
COALESCE(
|
|
symbol_out,
|
|
CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42))
|
|
)
|
|
),
|
|
'-',
|
|
GREATEST(
|
|
COALESCE(
|
|
symbol_in,
|
|
CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42))
|
|
),
|
|
COALESCE(
|
|
symbol_out,
|
|
CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42))
|
|
)
|
|
)
|
|
)
|
|
ELSE lp.pool_name
|
|
END AS pool_name,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
s.platform,
|
|
s.protocol,
|
|
s.version,
|
|
s._log_id,
|
|
s._inserted_timestamp
|
|
FROM
|
|
all_dex s
|
|
LEFT JOIN {{ ref('silver__contracts') }}
|
|
c1
|
|
ON s.token_in = c1.contract_address
|
|
LEFT JOIN {{ ref('silver__contracts') }}
|
|
c2
|
|
ON s.token_out = c2.contract_address
|
|
LEFT JOIN {{ ref('price__ez_prices_hourly') }}
|
|
p1
|
|
ON s.token_in = p1.token_address
|
|
AND DATE_TRUNC(
|
|
'hour',
|
|
block_timestamp
|
|
) = p1.hour
|
|
LEFT JOIN {{ ref('price__ez_prices_hourly') }}
|
|
p2
|
|
ON s.token_out = p2.token_address
|
|
AND DATE_TRUNC(
|
|
'hour',
|
|
block_timestamp
|
|
) = p2.hour
|
|
LEFT JOIN {{ ref('silver_dex__complete_dex_liquidity_pools') }}
|
|
lp
|
|
ON s.contract_address = lp.pool_address
|
|
),
|
|
|
|
{% if is_incremental() and var(
|
|
'HEAL_MODEL'
|
|
) %}
|
|
heal_model AS (
|
|
SELECT
|
|
t0.block_number,
|
|
t0.block_timestamp,
|
|
t0.tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
t0.contract_address,
|
|
event_name,
|
|
token_in,
|
|
p1.is_verified AS token_in_is_verified,
|
|
c1.token_decimals AS decimals_in,
|
|
c1.token_symbol AS symbol_in,
|
|
amount_in_unadj,
|
|
CASE
|
|
WHEN c1.token_decimals IS NULL THEN amount_in_unadj
|
|
ELSE (amount_in_unadj / pow(10, c1.token_decimals))
|
|
END AS amount_in_heal,
|
|
CASE
|
|
WHEN c1.token_decimals IS NOT NULL THEN amount_in_heal * p1.price
|
|
ELSE NULL
|
|
END AS amount_in_usd_heal,
|
|
token_out,
|
|
p2.is_verified AS token_out_is_verified,
|
|
c2.token_decimals AS decimals_out,
|
|
c2.token_symbol AS symbol_out,
|
|
amount_out_unadj,
|
|
CASE
|
|
WHEN c2.token_decimals IS NULL THEN amount_out_unadj
|
|
ELSE (amount_out_unadj / pow(10, c2.token_decimals))
|
|
END AS amount_out_heal,
|
|
CASE
|
|
WHEN c2.token_decimals IS NOT NULL THEN amount_out_heal * p2.price
|
|
ELSE NULL
|
|
END AS amount_out_usd_heal,
|
|
CASE
|
|
WHEN lp.pool_name IS NULL THEN CONCAT(
|
|
LEAST(
|
|
COALESCE(
|
|
c1.token_symbol,
|
|
CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42))
|
|
),
|
|
COALESCE(
|
|
c2.token_symbol,
|
|
CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42))
|
|
)
|
|
),
|
|
'-',
|
|
GREATEST(
|
|
COALESCE(
|
|
c1.token_symbol,
|
|
CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42))
|
|
),
|
|
COALESCE(
|
|
c2.token_symbol,
|
|
CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42))
|
|
)
|
|
)
|
|
)
|
|
ELSE lp.pool_name
|
|
END AS pool_name_heal,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
t0.platform,
|
|
t0.protocol,
|
|
t0.version,
|
|
t0._log_id,
|
|
t0._inserted_timestamp
|
|
FROM
|
|
{{ this }}
|
|
t0
|
|
LEFT JOIN {{ ref('silver__contracts') }}
|
|
c1
|
|
ON t0.token_in = c1.contract_address
|
|
LEFT JOIN {{ ref('silver__contracts') }}
|
|
c2
|
|
ON t0.token_out = c2.contract_address
|
|
LEFT JOIN {{ ref('price__ez_prices_hourly') }}
|
|
p1
|
|
ON t0.token_in = p1.token_address
|
|
AND DATE_TRUNC(
|
|
'hour',
|
|
block_timestamp
|
|
) = p1.hour
|
|
LEFT JOIN {{ ref('price__ez_prices_hourly') }}
|
|
p2
|
|
ON t0.token_out = p2.token_address
|
|
AND DATE_TRUNC(
|
|
'hour',
|
|
block_timestamp
|
|
) = p2.hour
|
|
LEFT JOIN {{ ref('silver_dex__complete_dex_liquidity_pools') }}
|
|
lp
|
|
ON t0.contract_address = lp.pool_address
|
|
WHERE
|
|
CONCAT(
|
|
t0.block_number,
|
|
'-',
|
|
t0.platform,
|
|
'-',
|
|
t0.version
|
|
) IN (
|
|
SELECT
|
|
CONCAT(
|
|
t1.block_number,
|
|
'-',
|
|
t1.platform,
|
|
'-',
|
|
t1.version
|
|
)
|
|
FROM
|
|
{{ this }}
|
|
t1
|
|
WHERE
|
|
t1.decimals_in IS NULL
|
|
AND t1._inserted_timestamp < (
|
|
SELECT
|
|
MAX(
|
|
_inserted_timestamp
|
|
) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
{{ ref('silver__contracts') }} C
|
|
WHERE
|
|
C._inserted_timestamp > DATEADD('DAY', -14, SYSDATE())
|
|
AND C.token_decimals IS NOT NULL
|
|
AND C.contract_address = t1.token_in)
|
|
GROUP BY
|
|
1
|
|
)
|
|
OR CONCAT(
|
|
t0.block_number,
|
|
'-',
|
|
t0.platform,
|
|
'-',
|
|
t0.version
|
|
) IN (
|
|
SELECT
|
|
CONCAT(
|
|
t2.block_number,
|
|
'-',
|
|
t2.platform,
|
|
'-',
|
|
t2.version
|
|
)
|
|
FROM
|
|
{{ this }}
|
|
t2
|
|
WHERE
|
|
t2.decimals_out IS NULL
|
|
AND t2._inserted_timestamp < (
|
|
SELECT
|
|
MAX(
|
|
_inserted_timestamp
|
|
) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
{{ ref('silver__contracts') }} C
|
|
WHERE
|
|
C._inserted_timestamp > DATEADD('DAY', -14, SYSDATE())
|
|
AND C.token_decimals IS NOT NULL
|
|
AND C.contract_address = t2.token_out)
|
|
GROUP BY
|
|
1
|
|
)
|
|
OR CONCAT(
|
|
t0.block_number,
|
|
'-',
|
|
t0.platform,
|
|
'-',
|
|
t0.version
|
|
) IN (
|
|
SELECT
|
|
CONCAT(
|
|
t3.block_number,
|
|
'-',
|
|
t3.platform,
|
|
'-',
|
|
t3.version
|
|
)
|
|
FROM
|
|
{{ this }}
|
|
t3
|
|
WHERE
|
|
t3.amount_in_usd IS NULL
|
|
AND t3._inserted_timestamp < (
|
|
SELECT
|
|
MAX(
|
|
_inserted_timestamp
|
|
) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
{{ ref('silver__complete_token_prices') }}
|
|
p
|
|
WHERE
|
|
p._inserted_timestamp > DATEADD('DAY', -14, SYSDATE())
|
|
AND p.price IS NOT NULL
|
|
AND p.token_address = t3.token_in
|
|
AND p.hour = DATE_TRUNC(
|
|
'hour',
|
|
t3.block_timestamp
|
|
)
|
|
)
|
|
GROUP BY
|
|
1
|
|
)
|
|
OR CONCAT(
|
|
t0.block_number,
|
|
'-',
|
|
t0.platform,
|
|
'-',
|
|
t0.version
|
|
) IN (
|
|
SELECT
|
|
CONCAT(
|
|
t4.block_number,
|
|
'-',
|
|
t4.platform,
|
|
'-',
|
|
t4.version
|
|
)
|
|
FROM
|
|
{{ this }}
|
|
t4
|
|
WHERE
|
|
t4.amount_out_usd IS NULL
|
|
AND t4._inserted_timestamp < (
|
|
SELECT
|
|
MAX(
|
|
_inserted_timestamp
|
|
) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
{{ ref('silver__complete_token_prices') }}
|
|
p
|
|
WHERE
|
|
p._inserted_timestamp > DATEADD('DAY', -14, SYSDATE())
|
|
AND p.price IS NOT NULL
|
|
AND p.token_address = t4.token_out
|
|
AND p.hour = DATE_TRUNC(
|
|
'hour',
|
|
t4.block_timestamp
|
|
)
|
|
)
|
|
GROUP BY
|
|
1
|
|
)
|
|
), newly_verified_tokens as (
|
|
select token_address
|
|
from {{ ref('price__ez_asset_metadata') }}
|
|
where ifnull(is_verified_modified_timestamp, '1970-01-01' :: TIMESTAMP) > dateadd('day', -10, SYSDATE())
|
|
),
|
|
heal_newly_verified_tokens as (
|
|
select
|
|
t0.block_number,
|
|
t0.block_timestamp,
|
|
t0.tx_hash,
|
|
t0.origin_function_signature,
|
|
t0.origin_from_address,
|
|
t0.origin_to_address,
|
|
t0.contract_address,
|
|
t0.event_name,
|
|
t0.token_in,
|
|
p1.is_verified AS token_in_is_verified,
|
|
t0.decimals_in,
|
|
t0.symbol_in,
|
|
t0.amount_in_unadj,
|
|
t0.amount_in,
|
|
CASE
|
|
WHEN decimals_in IS NOT NULL THEN amount_in * p1.price
|
|
ELSE NULL
|
|
END AS amount_in_usd_heal,
|
|
token_out,
|
|
p2.is_verified AS token_out_is_verified,
|
|
t0.decimals_out,
|
|
t0.symbol_out,
|
|
t0.amount_out_unadj,
|
|
t0.amount_out,
|
|
CASE
|
|
WHEN decimals_out IS NOT NULL THEN amount_out * p2.price
|
|
ELSE NULL
|
|
END AS amount_out_usd_heal,
|
|
t0.pool_name,
|
|
t0.sender,
|
|
t0.tx_to,
|
|
t0.event_index,
|
|
t0.platform,
|
|
t0.protocol,
|
|
t0.version,
|
|
t0._log_id,
|
|
t0._inserted_timestamp
|
|
from {{ this }} t0
|
|
join newly_verified_tokens nv
|
|
on (t0.token_in = nv.token_address or t0.token_out = nv.token_address)
|
|
left join {{ ref('price__ez_prices_hourly')}} p1
|
|
on t0.token_in = p1.token_address
|
|
and date_trunc('hour', t0.block_timestamp) = p1.hour
|
|
left join {{ ref('price__ez_prices_hourly')}} p2
|
|
on t0.token_out = p2.token_address
|
|
and date_trunc('hour', t0.block_timestamp) = p2.hour
|
|
),
|
|
{% endif %}
|
|
|
|
FINAL AS (
|
|
SELECT
|
|
*
|
|
FROM
|
|
complete_dex_swaps
|
|
|
|
{% if is_incremental() and var(
|
|
'HEAL_MODEL'
|
|
) %}
|
|
UNION ALL
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
token_in,
|
|
token_in_is_verified,
|
|
decimals_in,
|
|
symbol_in,
|
|
amount_in_unadj,
|
|
amount_in_heal AS amount_in,
|
|
amount_in_usd_heal AS amount_in_usd,
|
|
token_out,
|
|
token_out_is_verified,
|
|
decimals_out,
|
|
symbol_out,
|
|
amount_out_unadj,
|
|
amount_out_heal AS amount_out,
|
|
amount_out_usd_heal AS amount_out_usd,
|
|
pool_name_heal AS pool_name,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
protocol,
|
|
version,
|
|
_log_id,
|
|
_inserted_timestamp
|
|
FROM
|
|
heal_model
|
|
UNION ALL
|
|
SELECT
|
|
*
|
|
FROM
|
|
heal_newly_verified_tokens
|
|
{% endif %}
|
|
)
|
|
SELECT
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
pool_name,
|
|
event_name,
|
|
amount_in_unadj,
|
|
amount_in,
|
|
amount_in_usd,
|
|
amount_out_unadj,
|
|
amount_out,
|
|
amount_out_usd,
|
|
sender,
|
|
tx_to,
|
|
event_index,
|
|
platform,
|
|
protocol,
|
|
version,
|
|
token_in,
|
|
ifnull(token_in_is_verified, false) AS token_in_is_verified,
|
|
token_out,
|
|
ifnull(token_out_is_verified, false) AS token_out_is_verified,
|
|
symbol_in,
|
|
symbol_out,
|
|
decimals_in,
|
|
decimals_out,
|
|
_log_id,
|
|
_inserted_timestamp,
|
|
{{ dbt_utils.generate_surrogate_key(
|
|
['tx_hash','event_index']
|
|
) }} AS complete_dex_swaps_id,
|
|
SYSDATE() AS inserted_timestamp,
|
|
SYSDATE() AS modified_timestamp,
|
|
'{{ invocation_id }}' AS _invocation_id
|
|
FROM
|
|
FINAL qualify (ROW_NUMBER() over (PARTITION BY _log_id
|
|
ORDER BY
|
|
_inserted_timestamp DESC)) = 1
|