token id split, zeroifnull, split native price to separate cte for join

This commit is contained in:
Jack Forgash 2025-04-23 17:47:23 -06:00
parent 2e197e3e6a
commit 33895d3550

View File

@ -70,10 +70,14 @@ WITH intents AS (
amount_index,
amount_raw,
token_id,
SPLIT(
REGEXP_SUBSTR(
token_id,
'nep141:'
) [1] AS contract_address_raw,
'nep(141|245):(.*)',
1,
1,
'e',
2
) AS contract_address_raw,
referral,
dip4_version,
gas_burnt,
@ -149,14 +153,38 @@ prices AS (
SELECT
token_address AS contract_address,
symbol,
is_native,
price,
HOUR
FROM
{{ ref('price__ez_prices_hourly') }}
WHERE
NOT is_native
{% if is_incremental() or var('MANUAL_FIX') %}
WHERE
AND
DATE_TRUNC(
'day',
HOUR
) >= '{{ min_block_timestamp_day }}'
{% endif %}
qualify(ROW_NUMBER() over (PARTITION BY COALESCE(token_address, symbol), HOUR
ORDER BY
HOUR DESC) = 1)
),
prices_native AS (
SELECT
token_address AS contract_address,
symbol,
price,
HOUR
FROM
{{ ref('price__ez_prices_hourly') }}
WHERE
is_native
{% if is_incremental() or var('MANUAL_FIX') %}
AND
DATE_TRUNC(
'day',
HOUR
@ -204,10 +232,13 @@ FINAL AS (
) AS amount_adj,
-- We do not have USDC for every token on every chain, so fallback to 1
IFF(l.symbol ilike 'USD%', COALESCE(p.price, 1), COALESCE(p.price, p2.price)) AS price,
amount_raw / pow(
10,
l.decimals
) * IFF(l.symbol ilike 'USD%', COALESCE(p.price, 1), COALESCE(p.price, p2.price)) AS amount_usd
ZEROIFNULL(
amount_raw / pow(10, l.decimals) * IFF(
l.symbol ilike 'USD%',
COALESCE(p.price, 1),
COALESCE(p.price, p2.price)
)
) AS amount_usd
FROM
intents i
LEFT JOIN labels l
@ -220,13 +251,10 @@ FINAL AS (
ON (
l.contract_address = p.contract_address
)
ASOF JOIN prices p2 match_condition (
ASOF JOIN prices_native p2 match_condition (
i.block_timestamp >= p2.hour
)
ON (
(l.contract_address = 'native') = p2.is_native
AND upper(l.symbol) = upper(p2.symbol)
)
ON l.contract_address = p2.contract_address
)
SELECT
*,