fix labels parsing, update fee columns

This commit is contained in:
Jack Forgash 2025-11-11 17:02:31 -07:00
parent ace3c92085
commit 6884292157
4 changed files with 136 additions and 12 deletions

View File

@ -92,6 +92,16 @@ WITH intents AS (
) AS asset_identifier,
referral,
dip4_version,
fees_collected_raw,
REGEXP_SUBSTR(
object_keys(try_parse_json(fees_collected_raw))[0]::string,
'nep(141|171|245):(.*)',
1,
1,
'e',
2
) AS fee_asset_identifier,
try_parse_json(fees_collected_raw)[object_keys(try_parse_json(fees_collected_raw))[0]]::string as fee_amount_raw,
gas_burnt,
receipt_succeeded,
fact_intents_id,
@ -223,11 +233,32 @@ FINAL AS (
COALESCE(p.price, p2.price)
)
) AS amount_usd,
COALESCE(p.is_verified, p2.is_verified, FALSE) AS token_is_verified
COALESCE(p.is_verified, p2.is_verified, FALSE) AS token_is_verified,
-- fee information
fees_collected_raw,
l2.symbol AS fee_token,
i.fee_asset_identifier,
i.fee_amount_raw,
l2.decimals AS fee_decimals,
i.fee_amount_raw :: NUMBER / pow(
10,
l2.decimals
) AS fee_amount_adj,
ZEROIFNULL(
i.fee_amount_raw :: NUMBER / pow(10, l2.decimals) * IFF(
l2.symbol ilike 'USD%',
COALESCE(p_fee.price, 1),
COALESCE(p_fee.price, p2_fee.price)
)
) AS fee_amount_usd
FROM
intents i
LEFT JOIN labels l
ON i.asset_identifier = l.asset_identifier
-- label the fee token
LEFT JOIN labels l2
ON i.fee_asset_identifier = l2.asset_identifier
-- price the main token
ASOF JOIN prices p match_condition (
i.block_timestamp >= p.hour
)
@ -241,6 +272,20 @@ FINAL AS (
upper(l.symbol) = upper(p2.symbol)
AND (l.crosschain_token_contract = 'native') = p2.is_native
)
-- price the fee token
ASOF JOIN prices p_fee match_condition (
i.block_timestamp >= p_fee.hour
)
ON (
l2.crosschain_token_contract = p_fee.contract_address
)
ASOF JOIN prices_native p2_fee match_condition (
i.block_timestamp >= p2_fee.hour
)
ON (
upper(l2.symbol) = upper(p2_fee.symbol)
AND (l2.crosschain_token_contract = 'native') = p2_fee.is_native
)
)
SELECT
block_timestamp,
@ -266,6 +311,10 @@ SELECT
gas_burnt,
memo,
referral,
fees_collected_raw,
fee_token,
fee_amount_adj,
fee_amount_usd,
dip4_version,
log_index,
log_event_index,

View File

@ -113,6 +113,7 @@ dip4_logs AS (
SELECT
lb.*,
try_parse_json(lb.clean_log):data[0]:referral::string as referral,
try_parse_json(lb.clean_log):data[0]:fees_collected as fees_collected_raw,
try_parse_json(lb.clean_log):version :: string as version
FROM
logs_base lb
@ -197,6 +198,7 @@ SELECT
final.amount_raw,
final.token_id,
dip4.referral,
dip4.fees_collected_raw,
dip4.version AS dip4_version,
final.gas_burnt,
final.receipt_succeeded,

View File

@ -15,7 +15,10 @@ WITH api_call AS (
),
flattened AS (
SELECT
TRY_PARSE_JSON(VALUE) AS token_metadata,
VALUE :defuse_asset_identifier :: STRING AS defuse_asset_identifier,
VALUE :intents_token_id :: STRING AS intents_token_id,
VALUE :standard :: STRING AS standard,
VALUE :asset_name :: STRING AS asset_name,
VALUE :decimals :: INT AS decimals,
VALUE :min_deposit_amount :: STRING AS min_deposit_amount,
@ -27,15 +30,85 @@ FROM
LATERAL FLATTEN(
input => response :data :result :tokens :: ARRAY
)
),
chain_mapping AS (
-- Map EVM chain IDs to blockchain names
SELECT '1' AS chain_id, 'eth' AS blockchain_name UNION ALL
SELECT '10', 'op' UNION ALL
SELECT '56', 'bsc' UNION ALL
SELECT '100', 'gnosis' UNION ALL
SELECT '137', 'pol' UNION ALL
SELECT '8453', 'base' UNION ALL
SELECT '42161', 'arb' UNION ALL
SELECT '43114', 'avax' UNION ALL
SELECT '80094', 'bera' UNION ALL
SELECT '196', 'okx'
),
parsed AS (
SELECT
defuse_asset_identifier,
intents_token_id,
standard,
asset_name,
decimals,
min_deposit_amount,
min_withdrawal_amount,
near_token_contract,
withdrawal_fee,
-- Parse the asset_identifier (what ez_intents joins on)
CASE
WHEN standard = 'nep245' THEN
-- For NEP245: extract everything after "nep245:"
-- Example: nep245:v2_1.omni.hot.tg:56_11111111111111111111 -> v2_1.omni.hot.tg:56_11111111111111111111
REGEXP_SUBSTR(intents_token_id, 'nep245:(.*)', 1, 1, 'e', 1)
ELSE
-- For NEP141: use near_token_contract as before
near_token_contract
END AS asset_identifier,
-- Parse source_chain
CASE
WHEN standard = 'nep245' THEN
-- For NEP245: parse from defuse_asset_identifier
-- Format: blockchain:chainId:contractAddress
COALESCE(
cm.blockchain_name,
CASE
WHEN SPLIT_PART(defuse_asset_identifier, ':', 1) = 'ton' THEN 'ton'
WHEN SPLIT_PART(defuse_asset_identifier, ':', 1) = 'sol' THEN 'sol'
WHEN SPLIT_PART(defuse_asset_identifier, ':', 1) = 'stellar' THEN 'stellar'
ELSE 'unknown'
END
)
WHEN SPLIT_PART(defuse_asset_identifier, ':', 1) = 'near' THEN 'near'
WHEN SPLIT_PART(defuse_asset_identifier, ':', ARRAY_SIZE(SPLIT(defuse_asset_identifier, ':'))) = 'native' THEN
SPLIT_PART(near_token_contract, '.', 1) :: STRING
ELSE
SPLIT_PART(near_token_contract, '-', 1) :: STRING
END AS source_chain,
-- Parse crosschain_token_contract
CASE
WHEN standard = 'nep245' THEN
-- For NEP245: parse contract address from defuse_asset_identifier
CASE
WHEN SPLIT_PART(defuse_asset_identifier, ':', ARRAY_SIZE(SPLIT(defuse_asset_identifier, ':'))) = 'native' THEN 'native'
ELSE SPLIT_PART(defuse_asset_identifier, ':', ARRAY_SIZE(SPLIT(defuse_asset_identifier, ':')))
END
ELSE
SPLIT_PART(defuse_asset_identifier, ':', ARRAY_SIZE(SPLIT(defuse_asset_identifier, ':')))
END AS crosschain_token_contract,
-- Extract chain_id for mapping (second part of defuse_asset_identifier)
SPLIT_PART(defuse_asset_identifier, ':', 2) AS chain_id_for_mapping
FROM
flattened
LEFT JOIN chain_mapping cm
ON SPLIT_PART(flattened.defuse_asset_identifier, ':', 2) = cm.chain_id
AND flattened.standard = 'nep245'
)
SELECT
defuse_asset_identifier,
CASE
WHEN SPLIT_PART(defuse_asset_identifier, ':', 0) = 'near' THEN 'near'
WHEN SPLIT_PART(defuse_asset_identifier, ':', ARRAY_SIZE(SPLIT(defuse_asset_identifier, ':'))) = 'native' THEN SPLIT_PART(near_token_contract, '.', 0) :: STRING
ELSE SPLIT_PART(near_token_contract, '-', 0) :: STRING
END AS source_chain,
SPLIT_PART(defuse_asset_identifier, ':', ARRAY_SIZE(SPLIT(defuse_asset_identifier, ':'))) AS crosschain_token_contract,
asset_identifier,
source_chain,
crosschain_token_contract,
asset_name,
decimals,
min_deposit_amount,
@ -43,12 +116,12 @@ SELECT
near_token_contract,
withdrawal_fee,
{{ dbt_utils.generate_surrogate_key(
['defuse_asset_identifier']
['asset_identifier']
) }} AS defuse_ft_metadata_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
flattened
parsed
qualify(row_number() over (partition by defuse_asset_identifier order by inserted_timestamp asc)) = 1
qualify(row_number() over (partition by asset_identifier order by inserted_timestamp asc)) = 1

View File

@ -92,7 +92,7 @@ omni_unmapped AS (
),
defuse AS (
SELECT
d.near_token_contract AS asset_identifier,
d.asset_identifier,
d.source_chain,
d.crosschain_token_contract,
d.near_token_contract,