add defi bridge

This commit is contained in:
sam 2025-06-26 18:17:58 +08:00
parent 03bb00d864
commit fa6650e046
7 changed files with 614 additions and 2 deletions

View File

@ -101,6 +101,10 @@ models:
+enabled: true
stats:
+enabled: true
defi:
+enabled: false
bridge:
+enabled: true
scores_package:
+enabled: true

View File

@ -0,0 +1,64 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true },
meta ={
'database_tags':{
'table':{
'PROTOCOL': 'LAYERZERO, STARGATE',
'PURPOSE': 'BRIDGE'
} } },
tags = ['gold','defi','bridge','curated','ez']
) }}
SELECT
block_number,
block_timestamp,
origin_from_address,
origin_to_address,
origin_function_signature,
tx_hash,
event_index,
bridge_address,
event_name,
platform,
sender,
receiver,
destination_chain_receiver,
COALESCE(
c.standardized_name,
b.destination_chain
) AS destination_chain,
destination_chain_id,
token_address,
token_symbol,
amount_unadj,
amount,
ROUND(
CASE
WHEN amount_usd < 1e+15 THEN amount_usd
ELSE NULL
END,
2
) AS amount_usd,
token_is_verified,
COALESCE (
complete_bridge_activity_id,
{{ dbt_utils.generate_surrogate_key(
['_id']
) }}
) AS ez_bridge_activity_id,
COALESCE(
inserted_timestamp,
'2000-01-01'
) AS inserted_timestamp,
COALESCE(
modified_timestamp,
'2000-01-01'
) AS modified_timestamp
FROM
{{ ref('silver_bridge__complete_bridge_activity') }}
b
LEFT JOIN {{ ref('silver_bridge__standard_chain_seed') }} C
ON b.destination_chain = C.variation

View File

@ -0,0 +1,56 @@
version: 2
models:
- name: defi__ez_bridge_activity
description: '{{ doc("evm_ez_bridge_activity_table_doc") }}'
columns:
- name: BLOCK_NUMBER
description: '{{ doc("evm_block_number") }}'
- name: BLOCK_TIMESTAMP
description: '{{ doc("evm_block_timestamp") }}'
- name: TX_HASH
description: '{{ doc("evm_logs_tx_hash") }}'
- name: CONTRACT_ADDRESS
description: '{{ doc("evm_logs_contract_address") }}'
- name: EVENT_NAME
description: '{{ doc("evm_event_name") }}'
- name: EVENT_INDEX
description: '{{ doc("evm_event_index") }}'
- name: ORIGIN_FUNCTION_SIGNATURE
description: '{{ doc("evm_nft_origin_sig") }}'
- name: ORIGIN_FROM_ADDRESS
description: '{{ doc("evm_bridge_origin_from") }}'
- name: ORIGIN_TO_ADDRESS
description: '{{ doc("evm_origin_from") }}'
- name: PLATFORM
description: '{{ doc("evm_bridge_platform") }}'
- name: SENDER
description: '{{ doc("evm_bridge_sender") }}'
- name: RECEIVER
description: '{{ doc("evm_bridge_receiver") }}'
- name: DESTINATION_CHAIN_RECEIVER
description: '{{ doc("evm_bridge_destination_chain_receiver") }}'
- name: DESTINATION_CHAIN
description: '{{ doc("evm_bridge_destination_chain") }}'
- name: DESTINATION_CHAIN_ID
description: '{{ doc("evm_bridge_destination_chain_id") }}'
- name: BRIDGE_ADDRESS
description: '{{ doc("evm_bridge_address") }}'
- name: TOKEN_ADDRESS
description: '{{ doc("evm_bridge_token_address") }}'
- name: TOKEN_SYMBOL
description: '{{ doc("evm_bridge_token_symbol") }}'
- name: AMOUNT_UNADJ
description: '{{ doc("evm_bridge_amount_unadj") }}'
- name: AMOUNT
description: '{{ doc("evm_bridge_amount") }}'
- name: AMOUNT_USD
description: '{{ doc("evm_bridge_amount_usd") }}'
- name: TOKEN_IS_VERIFIED
description: '{{ doc("evm_prices_is_verified") }}'
- name: EZ_BRIDGE_ACTIVITY_ID
description: '{{ doc("evm_pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("evm_inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("evm_modified_timestamp") }}'

View File

@ -0,0 +1,400 @@
-- depends_on: {{ ref('silver__complete_token_prices') }}
{{ 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_from_address, origin_to_address, origin_function_signature, bridge_address, sender, receiver, destination_chain_receiver, destination_chain_id, destination_chain, token_address, token_symbol), SUBSTRING(origin_function_signature, bridge_address, sender, receiver, destination_chain_receiver, destination_chain, token_address, token_symbol)",
tags = ['silver_bridge','defi','bridge','curated','heal']
) }}
WITH layerzero_v2 AS (
SELECT
block_number,
block_timestamp,
origin_from_address,
origin_to_address,
origin_function_signature,
tx_hash,
event_index,
bridge_address,
event_name,
platform,
version,
sender,
receiver,
destination_chain_receiver,
destination_chain_id :: STRING AS destination_chain_id,
destination_chain,
token_address,
NULL AS token_symbol,
amount_unadj,
_log_id AS _id,
inserted_timestamp AS _inserted_timestamp
FROM
{{ ref('silver_bridge__layerzero_v2') }}
{% if is_incremental() and 'layerzero_v2' not in var('HEAL_MODELS') %}
WHERE
_inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
FROM
{{ this }}
)
{% endif %}
),
stargate_v2 AS (
SELECT
block_number,
block_timestamp,
origin_from_address,
origin_to_address,
origin_function_signature,
tx_hash,
event_index,
bridge_address,
event_name,
platform,
version,
sender,
receiver,
destination_chain_receiver,
destination_chain_id :: STRING AS destination_chain_id,
destination_chain,
token_address,
NULL AS token_symbol,
amount_unadj,
_log_id AS _id,
inserted_timestamp AS _inserted_timestamp
FROM
{{ ref('silver_bridge__stargate_v2') }}
{% if is_incremental() and 'stargate_v2' not in var('HEAL_MODELS') %}
WHERE
_inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "4 hours") }}'
FROM
{{ this }}
)
{% endif %}
),
all_protocols AS (
SELECT
*
FROM
layerzero_v2
UNION ALL
SELECT
*
FROM
stargate_v2
),
complete_bridge_activity AS (
SELECT
block_number,
block_timestamp,
origin_from_address,
origin_to_address,
origin_function_signature,
tx_hash,
event_index,
bridge_address,
event_name,
platform,
version,
sender,
receiver,
destination_chain_receiver,
CASE
WHEN CONCAT(
platform,
'-',
version
) IN (
'layerzero-v2',
'stargate-v2'
) THEN destination_chain_id :: STRING
WHEN d.chain_id IS NULL THEN destination_chain_id :: STRING
ELSE d.chain_id :: STRING
END AS destination_chain_id,
CASE
WHEN CONCAT(
platform,
'-',
version
) IN (
'layerzero-v2',
'stargate-v2'
) THEN LOWER(destination_chain)
WHEN d.chain IS NULL THEN LOWER(destination_chain)
ELSE LOWER(
d.chain
)
END AS destination_chain,
b.token_address,
CASE
WHEN platform = 'axelar' THEN COALESCE(
C.token_symbol,
b.token_symbol
)
ELSE C.token_symbol
END AS token_symbol,
C.token_decimals AS token_decimals,
amount_unadj,
CASE
WHEN C.token_decimals IS NOT NULL THEN (amount_unadj / pow(10, C.token_decimals))
ELSE amount_unadj
END AS amount,
CASE
WHEN C.token_decimals IS NOT NULL THEN ROUND(
amount * p.price,
2
)
ELSE NULL
END AS amount_usd,
p.is_verified AS token_is_verified,
_id,
b._inserted_timestamp
FROM
all_protocols b
LEFT JOIN {{ ref('silver__contracts') }} C
ON b.token_address = C.contract_address
LEFT JOIN {{ ref('price__ez_prices_hourly') }}
p
ON b.token_address = p.token_address
AND DATE_TRUNC(
'hour',
block_timestamp
) = p.hour
LEFT JOIN {{ source(
'external_gold_defillama',
'dim_chains'
) }}
d
ON d.chain_id :: STRING = b.destination_chain_id :: STRING
OR LOWER(
d.chain
) = LOWER(
b.destination_chain
)
),
{% if is_incremental() and var(
'HEAL_MODEL'
) %}
heal_model AS (
SELECT
block_number,
block_timestamp,
origin_from_address,
origin_to_address,
origin_function_signature,
tx_hash,
event_index,
bridge_address,
event_name,
platform,
version,
sender,
receiver,
destination_chain_receiver,
destination_chain_id,
destination_chain,
t0.token_address,
C.token_symbol AS token_symbol,
C.token_decimals AS token_decimals,
amount_unadj,
CASE
WHEN C.token_decimals IS NOT NULL THEN (amount_unadj / pow(10, C.token_decimals))
ELSE amount_unadj
END AS amount_heal,
CASE
WHEN C.token_decimals IS NOT NULL THEN amount_heal * p.price
ELSE NULL
END AS amount_usd_heal,
p.is_verified AS token_is_verified,
_id,
t0._inserted_timestamp
FROM
{{ this }}
t0
LEFT JOIN {{ ref('silver__contracts') }} C
ON t0.token_address = C.contract_address
LEFT JOIN {{ ref('price__ez_prices_hourly') }}
p
ON t0.token_address = p.token_address
AND DATE_TRUNC(
'hour',
block_timestamp
) = p.hour
WHERE
CONCAT(
t0.block_number,
'-',
t0.platform,
'-',
t0.version
) IN (
SELECT
CONCAT(
t1.block_number,
'-',
t1.platform,
'-',
t1.version
)
FROM
{{ this }}
t1
WHERE
t1.token_decimals 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_address)
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.amount_usd IS NULL
AND t2._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 = t2.token_address
AND p.hour = DATE_TRUNC(
'hour',
t2.block_timestamp
)
)
GROUP BY
1
)
),
{% endif %}
FINAL AS (
SELECT
*
FROM
complete_bridge_activity
{% if is_incremental() and var(
'HEAL_MODEL'
) %}
UNION ALL
SELECT
block_number,
block_timestamp,
origin_from_address,
origin_to_address,
origin_function_signature,
tx_hash,
event_index,
bridge_address,
event_name,
platform,
version,
sender,
receiver,
destination_chain_receiver,
destination_chain_id,
destination_chain,
token_address,
token_symbol,
token_decimals,
amount_unadj,
amount_heal AS amount,
amount_usd_heal AS amount_usd,
token_is_verified,
_id,
_inserted_timestamp
FROM
heal_model
{% endif %}
)
SELECT
block_number,
block_timestamp,
origin_from_address,
origin_to_address,
origin_function_signature,
tx_hash,
event_index,
bridge_address,
event_name,
platform,
version,
sender,
receiver,
destination_chain_receiver,
destination_chain_id,
destination_chain,
token_address,
token_symbol,
token_decimals,
amount_unadj,
amount,
amount_usd,
token_is_verified,
_id,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['_id']
) }} AS complete_bridge_activity_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
FINAL
WHERE
destination_chain <> 'mantle' qualify (ROW_NUMBER() over (PARTITION BY _id
ORDER BY
_inserted_timestamp DESC)) = 1

View File

@ -0,0 +1,83 @@
version: 2
models:
- name: silver_bridge__complete_bridge_activity
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- _ID
columns:
- name: BLOCK_NUMBER
tests:
- not_null
- name: BLOCK_TIMESTAMP
tests:
- not_null
- name: ORIGIN_FUNCTION_SIGNATURE
tests:
- not_null
- name: ORIGIN_FROM_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: ORIGIN_TO_ADDRESS
tests:
- not_null:
where: PLATFORM NOT IN ('stargate')
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: TX_HASH
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: EVENT_INDEX
tests:
- not_null:
where: VERSION <> 'v1-native' AND PLATFORM NOT IN ('wormhole','meson')
- name: EVENT_NAME
tests:
- not_null:
where: VERSION <> 'v1-native' AND PLATFORM NOT IN ('wormhole','meson')
- name: BRIDGE_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: DESTINATION_CHAIN
- not_null
- name: DESTINATION_CHAIN_RECEIVER
tests:
- not_null
- name: PLATFORM
- not_null
- name: VERSION
- not_null
- name: SENDER
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: RECEIVER
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: AMOUNT_UNADJ
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- DECIMAL
- FLOAT
- NUMBER
- name: TOKEN_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: _INSERTED_TIMESTAMP
tests:
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 3

View File

@ -54,4 +54,9 @@ sources:
schema: admin
tables:
- name: _master_keys
- name: rpc_node_logs
- name: rpc_node_logs
- name: external_gold_defillama
database: external
schema: defillama
tables:
- name: dim_chains

View File

@ -1,3 +1,3 @@
packages:
- git: https://github.com/FlipsideCrypto/fsc-evm.git
revision: v4.3.0
revision: layerzero-curation