This commit is contained in:
Eric Laurello 2025-07-28 19:11:43 -04:00
parent 91e9ce7960
commit cd709ea0eb
4 changed files with 376 additions and 0 deletions

View File

@ -0,0 +1,73 @@
-- depends_on: {{ ref('bronze__checkpoints') }}
{{ config (
materialized = "incremental",
unique_key = "tx_digest",
cluster_by = ['modified_timestamp::DATE','block_timestamp::DATE'],
incremental_predicates = ["dynamic_range_predicate", "block_timestamp::date"],
merge_exclude_columns = ["inserted_timestamp"],
tags = ['silver','defi','non_core']
) }}
WITH claims AS (
SELECT
checkpoint_number,
block_timestamp,
tx_digest,
event_index,
tx_sender,
parsed_json :message_key :source_chain :: INT AS source_chain,
FROM
sui.core.fact_events {# {{ ref('core__fact_events') }} #}
WHERE
tx_succeeded
AND event_address = '0x000000000000000000000000000000000000000000000000000000000000000b'
AND event_resource = 'TokenTransferClaimed' {# AND block_timestamp :: DATE >= '2025-07-01' #}
{% if is_incremental() %}
AND modified_timestamp >= (
SELECT
MAX(modified_timestamp)
FROM
{{ this }}
)
{% endif %}
),
bc AS (
SELECT
A.tx_digest,
b.event_index,
A.coin_type,
A.amount,
A.address_owner
FROM
sui.core.fact_balance_changes {# {{ ref('core__fact_balance_changes') }} #} A
JOIN claims b
ON A.tx_digest = b.tx_digest
WHERE
A.address_owner <> A.tx_sender
AND amount > 0
)
SELECT
A.checkpoint_number,
A.block_timestamp,
A.tx_digest,
A.tx_sender,
A.event_index,
A.source_chain,
0 AS destination_chain,
bc.amount,
NULL AS source_address,
bc.address_owner AS destination_address,
bc.coin_type,
'0x000000000000000000000000000000000000000000000000000000000000000b' AS bridge_address,
{{ dbt_utils.generate_surrogate_key(['tx_digest']) }} AS sui_bridge_inbound_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
claims A
JOIN bc USING (
tx_digest,
event_index
)

View File

@ -0,0 +1,139 @@
-- depends_on: {{ ref('bronze__checkpoints') }}
{{ config (
materialized = "incremental",
unique_key = "tx_digest",
cluster_by = ['modified_timestamp::DATE','block_timestamp::DATE'],
incremental_predicates = ["dynamic_range_predicate", "block_timestamp::date"],
merge_exclude_columns = ["inserted_timestamp"],
tags = ['silver','defi','non_core']
) }}
WITH base_events AS (
SELECT
checkpoint_number,
block_timestamp,
tx_digest,
tx_sender,
event_index,
parsed_json,
modified_timestamp
FROM
sui.core.fact_events {# {{ ref('core__fact_events') }} #}
WHERE
tx_succeeded
AND event_address = '0x000000000000000000000000000000000000000000000000000000000000000b'
AND event_resource = 'TokenDepositedEvent' {# AND block_timestamp :: DATE >= '2025-07-01' #}
{% if is_incremental() %}
WHERE
modified_timestamp >= (
SELECT
MAX(modified_timestamp)
FROM
{{ this }}
)
{% endif %}
),
deposits_base AS (
SELECT
checkpoint_number,
block_timestamp,
tx_digest,
tx_sender,
event_index,
'0x' || LISTAGG(
CASE
WHEN s.value :: INTEGER = 0 THEN '00'
WHEN s.value :: INTEGER < 16 THEN '0' || SUBSTR(
'0123456789abcdef',
s.value :: INTEGER + 1,
1
)
ELSE SUBSTR('0123456789abcdef', FLOOR(s.value :: INTEGER / 16) + 1, 1) || SUBSTR('0123456789abcdef', MOD(s.value :: INTEGER, 16) + 1, 1)
END,
''
) within GROUP (
ORDER BY
s.index
) AS sender_address,
parsed_json :source_chain :: STRING AS source_chain,
parsed_json :target_chain :: STRING AS target_chain,
parsed_json :token_type :: STRING AS token_type,
parsed_json :amount :: bigint AS amount,
parsed_json :seq_num :: INT AS seq_num,
modified_timestamp
FROM
base_events e,
LATERAL FLATTEN(
input => e.parsed_json :sender_address
) s
GROUP BY
ALL
),
deposits_target AS (
SELECT
tx_digest,
event_index,
'0x' || LISTAGG(
CASE
WHEN s.value :: INTEGER = 0 THEN '00'
WHEN s.value :: INTEGER < 16 THEN '0' || SUBSTR(
'0123456789abcdef',
s.value :: INTEGER + 1,
1
)
ELSE SUBSTR('0123456789abcdef', FLOOR(s.value :: INTEGER / 16) + 1, 1) || SUBSTR('0123456789abcdef', MOD(s.value :: INTEGER, 16) + 1, 1)
END,
''
) within GROUP (
ORDER BY
s.index
) AS target_address
FROM
base_events e,
LATERAL FLATTEN(
input => e.parsed_json :target_address
) s
GROUP BY
ALL
),
bc AS (
SELECT
A.tx_digest,
b.event_index,
A.coin_type
FROM
sui.core.fact_balance_changes {# {{ ref('core__fact_balance_changes') }} #} A
JOIN deposits_base b
ON A.tx_digest = b.tx_digest
AND A.address_owner = b.sender_address
AND - A.amount = b.amount
)
SELECT
A.checkpoint_number,
A.block_timestamp,
A.tx_digest,
A.tx_sender,
A.event_index,
A.source_chain,
A.target_chain AS destination_chain,
A.amount,
A.sender_address AS source_address,
b.target_address AS destination_address,
bc.coin_type,
'0x000000000000000000000000000000000000000000000000000000000000000b' AS bridge_address,
{{ dbt_utils.generate_surrogate_key(['tx_digest']) }} AS sui_bridge_outbound_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
deposits_base A
JOIN deposits_target b USING (
tx_digest,
event_index
)
JOIN bc USING (
tx_digest,
event_index
)

View File

@ -0,0 +1,71 @@
-- depends_on: {{ ref('bronze__checkpoints') }}
{{ config (
materialized = "incremental",
unique_key = "tx_digest",
cluster_by = ['modified_timestamp::DATE','block_timestamp::DATE'],
incremental_predicates = ["dynamic_range_predicate", "block_timestamp::date"],
merge_exclude_columns = ["inserted_timestamp"],
tags = ['silver','defi','non_core']
) }}
WITH wh_mess AS (
SELECT
checkpoint_number,
block_timestamp,
tx_digest,
event_index,
tx_sender
FROM
sui.core.fact_events {# {{ ref('core__fact_events') }} #}
WHERE
tx_succeeded
AND event_address = '0x26efee2b51c911237888e5dc6702868abca3c7ac12c53f76ef8eba0697695e3d'
AND event_resource = 'TransferRedeemed' {# AND block_timestamp :: DATE >= '2025-07-01' #}
{% if is_incremental() %}
AND modified_timestamp >= (
SELECT
MAX(modified_timestamp)
FROM
{{ this }}
)
{% endif %}
),
bc AS (
SELECT
A.tx_digest,
b.event_index,
A.coin_type,
A.amount
FROM
sui.core.fact_balance_changes {# {{ ref('core__fact_balance_changes') }} #} A
JOIN wh_mess b
ON A.tx_digest = b.tx_digest
WHERE
amount > 0
AND A.address_owner = A.tx_sender
)
SELECT
A.checkpoint_number,
A.block_timestamp,
A.tx_digest,
A.tx_sender,
A.event_index,
NULL AS source_chain,
0 AS destination_chain,
bc.amount AS amount,
NULL AS source_address,
A.tx_sender AS destination_address,
bc.coin_type,
'0x26efee2b51c911237888e5dc6702868abca3c7ac12c53f76ef8eba0697695e3d' AS bridge_address,
{{ dbt_utils.generate_surrogate_key(['a.tx_digest']) }} AS wormhole_outbound_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
wh_mess A
JOIN bc USING (
tx_digest,
event_index
)

View File

@ -0,0 +1,93 @@
-- depends_on: {{ ref('bronze__checkpoints') }}
{{ config (
materialized = "incremental",
unique_key = "tx_digest",
cluster_by = ['modified_timestamp::DATE','block_timestamp::DATE'],
incremental_predicates = ["dynamic_range_predicate", "block_timestamp::date"],
merge_exclude_columns = ["inserted_timestamp"],
tags = ['silver','defi','non_core']
) }}
WITH wh_mess AS (
SELECT
checkpoint_number,
block_timestamp,
tx_digest,
event_index,
tx_sender,
parsed_json,
CASE
WHEN event_address = '0x5306f64e312b581766351c07af79c72fcb1cd25147157fdc2f8ad76de9a3fb6a' THEN TRUE
ELSE FALSE
END AS is_basic
FROM
sui.core.fact_events {# {{ ref('core__fact_events') }} #}
WHERE
tx_succeeded
AND (
(
event_address = '0x5306f64e312b581766351c07af79c72fcb1cd25147157fdc2f8ad76de9a3fb6a'
AND event_resource = 'WormholeMessage' {# AND block_timestamp :: DATE >= '2025-07-01' #}
)
OR (
package_id = '0x2aa6c5d56376c371f88a6cc42e852824994993cb9bab8d3e6450cbe3cb32b94e'
AND event_resource = 'DepositForBurn' {# AND block_timestamp :: DATE >= '2025-07-01' #}
)
)
{% if is_incremental() %}
AND modified_timestamp >= (
SELECT
MAX(modified_timestamp)
FROM
{{ this }}
)
{% endif %}
),
bc AS (
SELECT
A.tx_digest,
b.event_index,
A.coin_type,
A.amount
FROM
sui.core.fact_balance_changes {# {{ ref('core__fact_balance_changes') }} #} A
JOIN wh_mess b
ON A.tx_digest = b.tx_digest
AND A.address_owner = b.tx_sender
WHERE
amount < 0
AND coin_type <> '0x2::sui::SUI'
)
SELECT
A.checkpoint_number,
A.block_timestamp,
A.tx_digest,
A.tx_sender,
A.event_index,
0 AS source_chain,
NULL AS destination_chain,
COALESCE(
-1 * bc.amount,
C.parsed_json :amount :: INT
) AS amount,
A.tx_sender AS source_address,
NULL AS destination_address,
bc.coin_type,
'0x5306f64e312b581766351c07af79c72fcb1cd25147157fdc2f8ad76de9a3fb6a' AS bridge_address,
{{ dbt_utils.generate_surrogate_key(['a.tx_digest']) }} AS wormhole_outbound_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
wh_mess A
JOIN bc USING (
tx_digest,
event_index
)
LEFT JOIN wh_mess C
ON A.tx_digest = C.tx_digest
AND C.is_basic = FALSE
WHERE
A.is_basic