mirror of
https://github.com/FlipsideCrypto/flow-models.git
synced 2026-02-06 11:26:53 +00:00
Layerzero bridge (#446)
* add * added * aded * updated * updated * csv * updated * added * updated name * add createpool add inc predicates * changes pool file * added * removed limit * updates * removed commented code --------- Co-authored-by: SAI <sairaj@flipsidecrypto.com> Co-authored-by: Eric Laurello <eric.laurello@flipsidecrypto.com>
This commit is contained in:
parent
d25d15f5ac
commit
bf21d191fb
48
data/seeds__layerzero_endpoint_ids.csv
Normal file
48
data/seeds__layerzero_endpoint_ids.csv
Normal file
@ -0,0 +1,48 @@
|
|||||||
|
endpoint_id,blockchain
|
||||||
|
30280,sei
|
||||||
|
30177,kava
|
||||||
|
30151,metis
|
||||||
|
223,b2
|
||||||
|
30106,avalanche
|
||||||
|
30295,flare
|
||||||
|
30324,abstract
|
||||||
|
30109,polygon
|
||||||
|
30362,flow_evm
|
||||||
|
30312,ape
|
||||||
|
30294,gravity
|
||||||
|
30168,solana
|
||||||
|
30165,zksync_era
|
||||||
|
30217,manta
|
||||||
|
30181,mantle
|
||||||
|
30138,fuse
|
||||||
|
30150,kaia
|
||||||
|
30330,vana
|
||||||
|
30235,rari
|
||||||
|
30332,sonic
|
||||||
|
30302,peaq
|
||||||
|
30364,story
|
||||||
|
30327,superposition
|
||||||
|
30153,coredao
|
||||||
|
30284,lota
|
||||||
|
30145,gnosis
|
||||||
|
30267,degen
|
||||||
|
30309,lightlink
|
||||||
|
30211,aurora
|
||||||
|
30340,soneium
|
||||||
|
30255,fraxtal
|
||||||
|
30214,scroll
|
||||||
|
30111,optimism
|
||||||
|
30184,base
|
||||||
|
30260,mod
|
||||||
|
34443,mod
|
||||||
|
30102,bsc
|
||||||
|
30243,blast
|
||||||
|
30329,hemi
|
||||||
|
288,boba
|
||||||
|
30290,taiko
|
||||||
|
30183,linea
|
||||||
|
59144,linea
|
||||||
|
30110,arbitrum
|
||||||
|
30303,zircuit
|
||||||
|
30101,ethereum
|
||||||
|
1,ethereum
|
||||||
|
@ -0,0 +1,134 @@
|
|||||||
|
{{ config(
|
||||||
|
materialized = 'incremental',
|
||||||
|
incremental_strategy = 'delete+insert',
|
||||||
|
unique_key = "block_number",
|
||||||
|
tags = ['silver_bridge','defi','bridge','curated']
|
||||||
|
) }}
|
||||||
|
|
||||||
|
WITH base_contracts AS (
|
||||||
|
|
||||||
|
SELECT
|
||||||
|
tx_hash,
|
||||||
|
block_number,
|
||||||
|
block_timestamp,
|
||||||
|
from_address,
|
||||||
|
to_address AS contract_address,
|
||||||
|
concat_ws(
|
||||||
|
'-',
|
||||||
|
block_number,
|
||||||
|
tx_position,
|
||||||
|
CONCAT(
|
||||||
|
TYPE,
|
||||||
|
'_',
|
||||||
|
trace_address
|
||||||
|
)
|
||||||
|
) AS _call_id,
|
||||||
|
modified_timestamp AS _inserted_timestamp
|
||||||
|
FROM
|
||||||
|
{{ ref('core_evm__fact_traces') }}
|
||||||
|
WHERE
|
||||||
|
from_address = '0x1d7c6783328c145393e84fb47a7f7c548f5ee28d'
|
||||||
|
AND TYPE ILIKE 'create%'
|
||||||
|
AND tx_succeeded
|
||||||
|
AND trace_succeeded
|
||||||
|
|
||||||
|
{% if is_incremental() %}
|
||||||
|
AND _inserted_timestamp >= (
|
||||||
|
SELECT
|
||||||
|
MAX(_inserted_timestamp) - INTERVAL '12 hours'
|
||||||
|
FROM
|
||||||
|
{{ this }}
|
||||||
|
)
|
||||||
|
AND to_address NOT IN (
|
||||||
|
SELECT
|
||||||
|
DISTINCT pool_address
|
||||||
|
FROM
|
||||||
|
{{ this }}
|
||||||
|
)
|
||||||
|
{% endif %}
|
||||||
|
),
|
||||||
|
function_sigs AS (
|
||||||
|
SELECT
|
||||||
|
'0xfc0c546a' AS function_sig,
|
||||||
|
'token' AS function_name
|
||||||
|
),
|
||||||
|
inputs AS (
|
||||||
|
SELECT
|
||||||
|
contract_address,
|
||||||
|
block_number,
|
||||||
|
function_sig,
|
||||||
|
function_name,
|
||||||
|
0 AS function_input,
|
||||||
|
CONCAT(
|
||||||
|
function_sig,
|
||||||
|
LPAD(
|
||||||
|
function_input,
|
||||||
|
64,
|
||||||
|
0
|
||||||
|
)
|
||||||
|
) AS DATA
|
||||||
|
FROM
|
||||||
|
base_contracts
|
||||||
|
JOIN function_sigs
|
||||||
|
ON 1 = 1
|
||||||
|
),
|
||||||
|
contract_reads AS (
|
||||||
|
SELECT
|
||||||
|
contract_address,
|
||||||
|
block_number,
|
||||||
|
function_sig,
|
||||||
|
function_name,
|
||||||
|
function_input,
|
||||||
|
DATA,
|
||||||
|
utils.udf_json_rpc_call(
|
||||||
|
'eth_call',
|
||||||
|
[{ 'to': contract_address, 'from': null, 'data': data }, utils.udf_int_to_hex(block_number) ]
|
||||||
|
) AS rpc_request,
|
||||||
|
live.udf_api(
|
||||||
|
'POST',
|
||||||
|
CONCAT(
|
||||||
|
'{Service}',
|
||||||
|
'/',
|
||||||
|
'{Authentication}'
|
||||||
|
),{},
|
||||||
|
rpc_request,
|
||||||
|
'Vault/prod/flow/quicknode/mainnet'
|
||||||
|
) AS read_output,
|
||||||
|
SYSDATE() AS _inserted_timestamp
|
||||||
|
FROM
|
||||||
|
inputs
|
||||||
|
),
|
||||||
|
reads_flat AS (
|
||||||
|
SELECT
|
||||||
|
read_output,
|
||||||
|
read_output :data :id :: STRING AS read_id,
|
||||||
|
read_output :data :result :: STRING AS read_result,
|
||||||
|
SPLIT(
|
||||||
|
read_id,
|
||||||
|
'-'
|
||||||
|
) AS read_id_object,
|
||||||
|
function_sig,
|
||||||
|
function_name,
|
||||||
|
function_input,
|
||||||
|
DATA,
|
||||||
|
contract_address,
|
||||||
|
block_number,
|
||||||
|
_inserted_timestamp
|
||||||
|
FROM
|
||||||
|
contract_reads
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
read_output,
|
||||||
|
read_id,
|
||||||
|
read_result,
|
||||||
|
read_id_object,
|
||||||
|
function_sig,
|
||||||
|
function_name,
|
||||||
|
function_input,
|
||||||
|
DATA,
|
||||||
|
block_number,
|
||||||
|
contract_address AS pool_address,
|
||||||
|
CONCAT('0x', SUBSTR(read_result, 27, 40)) AS token_address,
|
||||||
|
_inserted_timestamp
|
||||||
|
FROM
|
||||||
|
reads_flat
|
||||||
195
models/silver/transfers/silver_evm__bridge_stargate_s.sql
Normal file
195
models/silver/transfers/silver_evm__bridge_stargate_s.sql
Normal file
@ -0,0 +1,195 @@
|
|||||||
|
{{ config(
|
||||||
|
materialized = 'incremental',
|
||||||
|
incremental_strategy = 'merge',
|
||||||
|
merge_exclude_columns = ['inserted_timestamp'],
|
||||||
|
incremental_predicates = ["COALESCE(DBT_INTERNAL_DEST.block_timestamp::DATE,'2099-12-31') >= (select min(block_timestamp::DATE) from " ~ generate_tmp_view_name(this) ~ ")"],
|
||||||
|
cluster_by = ['modified_timestamp::date'],
|
||||||
|
unique_key = 'tx_id',
|
||||||
|
tags = ['bridge', 'scheduled', 'streamline_scheduled', 'scheduled_non_core', 'stargate']
|
||||||
|
) }}
|
||||||
|
|
||||||
|
WITH pools AS (
|
||||||
|
SELECT
|
||||||
|
pool_address,
|
||||||
|
LOWER(token_address) AS token_address
|
||||||
|
FROM
|
||||||
|
{{ ref('silver_evm__bridge_stargate_create_pool') }}
|
||||||
|
),
|
||||||
|
events AS (
|
||||||
|
SELECT
|
||||||
|
block_number AS block_height,
|
||||||
|
block_timestamp,
|
||||||
|
tx_hash AS tx_id,
|
||||||
|
event_index,
|
||||||
|
contract_address AS event_contract,
|
||||||
|
p.token_address,
|
||||||
|
event_name AS event_type,
|
||||||
|
decoded_log AS event_data,
|
||||||
|
modified_timestamp,
|
||||||
|
inserted_timestamp AS _inserted_timestamp
|
||||||
|
FROM
|
||||||
|
{{ ref('core_evm__ez_decoded_event_logs') }}
|
||||||
|
e
|
||||||
|
INNER JOIN pools p
|
||||||
|
ON e.contract_address = p.pool_address
|
||||||
|
WHERE
|
||||||
|
block_timestamp :: DATE >= '2025-01-29' -- first date of Stargate events
|
||||||
|
AND event_name IN (
|
||||||
|
'OFTSent',
|
||||||
|
'OFTReceived'
|
||||||
|
)
|
||||||
|
AND event_data IS NOT NULL
|
||||||
|
|
||||||
|
|
||||||
|
{% if is_incremental() %}
|
||||||
|
AND modified_timestamp >= (
|
||||||
|
SELECT
|
||||||
|
MAX(modified_timestamp)
|
||||||
|
FROM
|
||||||
|
{{ this }}
|
||||||
|
)
|
||||||
|
{% endif %}
|
||||||
|
|
||||||
|
),
|
||||||
|
-- Process OFTSent events (outbound transfers)
|
||||||
|
oft_sent_events AS (
|
||||||
|
SELECT
|
||||||
|
tx_id,
|
||||||
|
block_timestamp,
|
||||||
|
block_height,
|
||||||
|
event_index,
|
||||||
|
event_contract AS bridge_contract,
|
||||||
|
event_data :amountSentLD :: DOUBLE AS sent_amount,
|
||||||
|
event_data :amountReceivedLD :: DOUBLE AS received_amount,
|
||||||
|
COALESCE(
|
||||||
|
sent_amount - received_amount,
|
||||||
|
0
|
||||||
|
) AS fee_amount,
|
||||||
|
LOWER(
|
||||||
|
event_data :fromAddress :: STRING
|
||||||
|
) AS flow_wallet_address,
|
||||||
|
token_address,
|
||||||
|
event_data :dstEid :: NUMBER AS dst_endpoint_id,
|
||||||
|
30362 AS src_endpoint_id,
|
||||||
|
event_data :guid :: STRING AS transfer_guid,
|
||||||
|
'outbound' AS direction,
|
||||||
|
'stargate' AS bridge,
|
||||||
|
_inserted_timestamp
|
||||||
|
FROM
|
||||||
|
events
|
||||||
|
WHERE
|
||||||
|
event_type = 'OFTSent'
|
||||||
|
),
|
||||||
|
-- Process OFTReceived events (inbound transfers)
|
||||||
|
oft_received_events AS (
|
||||||
|
SELECT
|
||||||
|
tx_id,
|
||||||
|
block_timestamp,
|
||||||
|
block_height,
|
||||||
|
event_index,
|
||||||
|
event_contract AS bridge_contract,
|
||||||
|
event_data :amountReceivedLD :: DOUBLE AS received_amount,
|
||||||
|
0 AS fee_amount,
|
||||||
|
received_amount AS net_amount,
|
||||||
|
LOWER(
|
||||||
|
event_data :toAddress :: STRING
|
||||||
|
) AS flow_wallet_address,
|
||||||
|
token_address,
|
||||||
|
NULL AS dst_endpoint_id,
|
||||||
|
event_data :srcEid :: NUMBER AS src_endpoint_id,
|
||||||
|
event_data :guid :: STRING AS transfer_guid,
|
||||||
|
'inbound' AS direction,
|
||||||
|
'stargate' AS bridge,
|
||||||
|
_inserted_timestamp
|
||||||
|
FROM
|
||||||
|
events
|
||||||
|
WHERE
|
||||||
|
event_type = 'OFTReceived'
|
||||||
|
),
|
||||||
|
combined_events AS (
|
||||||
|
SELECT
|
||||||
|
tx_id,
|
||||||
|
block_timestamp,
|
||||||
|
block_height,
|
||||||
|
event_index,
|
||||||
|
bridge_contract,
|
||||||
|
sent_amount AS gross_amount,
|
||||||
|
fee_amount,
|
||||||
|
received_amount AS net_amount,
|
||||||
|
flow_wallet_address,
|
||||||
|
token_address,
|
||||||
|
src_endpoint_id,
|
||||||
|
dst_endpoint_id,
|
||||||
|
transfer_guid,
|
||||||
|
direction,
|
||||||
|
bridge,
|
||||||
|
_inserted_timestamp
|
||||||
|
FROM
|
||||||
|
oft_sent_events
|
||||||
|
UNION ALL
|
||||||
|
SELECT
|
||||||
|
tx_id,
|
||||||
|
block_timestamp,
|
||||||
|
block_height,
|
||||||
|
event_index,
|
||||||
|
bridge_contract,
|
||||||
|
received_amount AS gross_amount,
|
||||||
|
fee_amount,
|
||||||
|
net_amount,
|
||||||
|
flow_wallet_address,
|
||||||
|
token_address,
|
||||||
|
src_endpoint_id,
|
||||||
|
dst_endpoint_id,
|
||||||
|
transfer_guid,
|
||||||
|
direction,
|
||||||
|
bridge,
|
||||||
|
_inserted_timestamp
|
||||||
|
FROM
|
||||||
|
oft_received_events
|
||||||
|
),
|
||||||
|
|
||||||
|
endpoint_ids AS (
|
||||||
|
SELECT
|
||||||
|
endpoint_id,
|
||||||
|
LOWER(blockchain) AS blockchain
|
||||||
|
FROM
|
||||||
|
{{ ref('seeds__layerzero_endpoint_ids') }}
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
ce.tx_id,
|
||||||
|
ce.block_timestamp,
|
||||||
|
ce.block_height,
|
||||||
|
ce.bridge_contract AS bridge_address,
|
||||||
|
ce.token_address,
|
||||||
|
ce.gross_amount,
|
||||||
|
ce.fee_amount AS amount_fee,
|
||||||
|
ce.net_amount,
|
||||||
|
ce.flow_wallet_address,
|
||||||
|
CASE
|
||||||
|
WHEN ce.direction = 'outbound' THEN 'flow_evm'
|
||||||
|
ELSE COALESCE(
|
||||||
|
src.blockchain,
|
||||||
|
'other_chains'
|
||||||
|
)
|
||||||
|
END AS source_chain,
|
||||||
|
CASE
|
||||||
|
WHEN ce.direction = 'inbound' THEN 'flow_evm'
|
||||||
|
ELSE COALESCE(
|
||||||
|
dst.blockchain,
|
||||||
|
'other_chains'
|
||||||
|
)
|
||||||
|
END AS destination_chain,
|
||||||
|
ce.direction,
|
||||||
|
ce.bridge AS platform,
|
||||||
|
ce.transfer_guid,
|
||||||
|
ce._inserted_timestamp,
|
||||||
|
{{ dbt_utils.generate_surrogate_key(['ce.tx_id', 'ce.event_index']) }} AS bridge_startgate_id,
|
||||||
|
SYSDATE() AS inserted_timestamp,
|
||||||
|
SYSDATE() AS modified_timestamp,
|
||||||
|
'{{ invocation_id }}' AS _invocation_id
|
||||||
|
FROM
|
||||||
|
combined_events ce
|
||||||
|
LEFT JOIN endpoint_ids src
|
||||||
|
ON src.endpoint_id = ce.src_endpoint_id
|
||||||
|
LEFT JOIN endpoint_ids dst
|
||||||
|
ON dst.endpoint_id = ce.dst_endpoint_id
|
||||||
154
models/silver/transfers/silver_evm__bridge_stargate_s.yml
Normal file
154
models/silver/transfers/silver_evm__bridge_stargate_s.yml
Normal file
@ -0,0 +1,154 @@
|
|||||||
|
version: 2
|
||||||
|
|
||||||
|
models:
|
||||||
|
- name: silver_evm__bridge_stargate_s
|
||||||
|
description: |-
|
||||||
|
This table parses transactions where tokens are bridged to or from the Flow EVM network using the Stargate (LayerZero) messaging protocol.
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- tx_id
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: tx_id
|
||||||
|
description: "Transaction hash (unique for each bridge event)"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: block_timestamp
|
||||||
|
description: "Block timestamp of the event"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||||
|
datepart: day
|
||||||
|
interval: 3
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- TIMESTAMP_NTZ
|
||||||
|
|
||||||
|
- name: block_height
|
||||||
|
description: "Block number of the event"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- NUMBER
|
||||||
|
- FLOAT
|
||||||
|
|
||||||
|
- name: bridge_address
|
||||||
|
description: "The Stargate endpoint contract address"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: token_address
|
||||||
|
description: "The address of the token being transferred (if applicable)"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: gross_amount
|
||||||
|
description: "Gross amount sent or received in the transfer"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- NUMBER
|
||||||
|
- DOUBLE
|
||||||
|
- FLOAT
|
||||||
|
|
||||||
|
- name: amount_fee
|
||||||
|
description: "Fee amount for the transfer (if available)"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- NUMBER
|
||||||
|
- DOUBLE
|
||||||
|
- FLOAT
|
||||||
|
|
||||||
|
- name: net_amount
|
||||||
|
description: "Net amount received after fees (if available)"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- NUMBER
|
||||||
|
- DOUBLE
|
||||||
|
- FLOAT
|
||||||
|
|
||||||
|
- name: flow_wallet_address
|
||||||
|
description: "Flow wallet address involved in the transfer"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: source_chain
|
||||||
|
description: "Source blockchain for the message, mapped using Stargate endpoint IDs seed."
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: destination_chain
|
||||||
|
description: "Destination blockchain for the message, mapped using Stargate endpoint IDs seed."
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: direction
|
||||||
|
description: "Direction of the bridge transaction (inbound or outbound)"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: platform
|
||||||
|
description: "Bridge platform name (always 'stargate')"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: transfer_guid
|
||||||
|
description: "Unique transfer identifier from Stargate event logs"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- STRING
|
||||||
|
- VARCHAR
|
||||||
|
|
||||||
|
- name: _inserted_timestamp
|
||||||
|
description: "Timestamp when this record was inserted (raw event)"
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||||
|
column_type_list:
|
||||||
|
- TIMESTAMP_NTZ
|
||||||
|
|
||||||
|
- name: bridge_stargate_id
|
||||||
|
description: "Unique identifier for this record (surrogate key)"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: inserted_timestamp
|
||||||
|
description: "Timestamp when this record was inserted"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: modified_timestamp
|
||||||
|
description: "Timestamp when this record was last modified"
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: _invocation_id
|
||||||
|
description: "Invocation ID for this dbt run"
|
||||||
Loading…
Reference in New Issue
Block a user