mirror of
https://github.com/FlipsideCrypto/flow-models.git
synced 2026-02-06 11:06:45 +00:00
An 1346/bridges (#33)
* just a couple ctes * add array * blocto inbound * blocto teleports final * celer bridge * tweaks * core view * docs * docs * list columns, add incremental to celer, move bridge.md to right dir
This commit is contained in:
parent
a1bdcbb529
commit
6ceec78b93
52
models/core/core__fact_bridge_transactions.sql
Normal file
52
models/core/core__fact_bridge_transactions.sql
Normal file
@ -0,0 +1,52 @@
|
||||
{{ config(
|
||||
materialized = 'view'
|
||||
) }}
|
||||
|
||||
WITH blocto AS (
|
||||
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
{{ ref('silver__bridge_blocto') }}
|
||||
),
|
||||
celer AS (
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
{{ ref('silver__bridge_celer') }}
|
||||
),
|
||||
combo AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
teleport_contract AS bridge_contract,
|
||||
token_contract,
|
||||
gross_amount AS amount,
|
||||
flow_wallet_address,
|
||||
blockchain,
|
||||
teleport_direction AS direction,
|
||||
bridge
|
||||
FROM
|
||||
blocto
|
||||
UNION
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
bridge_contract,
|
||||
token_contract,
|
||||
amount,
|
||||
flow_wallet_address,
|
||||
blockchain,
|
||||
direction,
|
||||
bridge
|
||||
FROM
|
||||
celer
|
||||
)
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
combo
|
||||
WHERE
|
||||
block_timestamp >= '2022-04-20'
|
||||
100
models/core/core__fact_bridge_transactions.yml
Normal file
100
models/core/core__fact_bridge_transactions.yml
Normal file
@ -0,0 +1,100 @@
|
||||
version: 2
|
||||
|
||||
models:
|
||||
- name: core__fact_bridge_transactions
|
||||
description: |-
|
||||
This table parses transactions where tokens are bridged to or from the Flow network.
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- tx_id
|
||||
|
||||
columns:
|
||||
- name: tx_id
|
||||
description: "{{ doc('tx_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: block_timestamp
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 1
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
|
||||
- name: block_height
|
||||
description: "{{ doc('block_height') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
|
||||
- name: bridge_contract
|
||||
description: "{{ doc('bridge_contract') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: token_contract
|
||||
description: "{{ doc('token_contract') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: amount
|
||||
description: "{{ doc('amount') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- DOUBLE
|
||||
- FLOAT
|
||||
|
||||
- name: flow_wallet_address
|
||||
description: "{{ doc('flow_wallet_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: blockchain
|
||||
description: "{{ doc('blockchain') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: direction
|
||||
description: "{{ doc('direction') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: bridge
|
||||
description: "{{ doc('bridge') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
5
models/descriptions/amount.md
Normal file
5
models/descriptions/amount.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs amount %}
|
||||
|
||||
The amount of the asset involved in the transaction.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/amount_fee.md
Normal file
5
models/descriptions/amount_fee.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs amount_fee %}
|
||||
|
||||
The fee taken by the protocol or contract as part of the transaction.
|
||||
|
||||
{% enddocs %}
|
||||
@ -1,5 +1,5 @@
|
||||
{% docs blockchain %}
|
||||
|
||||
The name of the blockchain for this address.
|
||||
The name of the blockchain for this address or transaction.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/bridge.md
Normal file
5
models/descriptions/bridge.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs bridge %}
|
||||
|
||||
The name of the bridge or protocol used.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/bridge_contract.md
Normal file
5
models/descriptions/bridge_contract.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs bridge_contract %}
|
||||
|
||||
The contract address for the bridge used to move tokens to or from Flow.
|
||||
|
||||
{% enddocs %}
|
||||
6
models/descriptions/counterparty.md
Normal file
6
models/descriptions/counterparty.md
Normal file
@ -0,0 +1,6 @@
|
||||
{% docs counterparty %}
|
||||
|
||||
The alternate address involved in this transaction, if available.
|
||||
For bridge transactions, this may be the address on another blockchain.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/direction.md
Normal file
5
models/descriptions/direction.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs direction %}
|
||||
|
||||
For bridging transactions, inbound refers to tokens bridged to the Flow blockchain, while outbound indicated tokens were sent from Flow to another (i.e. to Ethereum, BSC, etc.).
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/flow_wallet_address.md
Normal file
5
models/descriptions/flow_wallet_address.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs flow_wallet_address %}
|
||||
|
||||
Address of a FLOW wallet related to the transaction.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/gross_amount.md
Normal file
5
models/descriptions/gross_amount.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs gross_amount %}
|
||||
|
||||
The amount of the asset involved in the transaction, before any fees or royalities.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/net_amount.md
Normal file
5
models/descriptions/net_amount.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs net_amount %}
|
||||
|
||||
The amount of the asset involved in the transaction, net of any fees or royalties.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/teleport_contract.md
Normal file
5
models/descriptions/teleport_contract.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs teleport_contract %}
|
||||
|
||||
The contract address for the bridge used to move tokens to or from Flow.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/teleport_direction.md
Normal file
5
models/descriptions/teleport_direction.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs teleport_direction %}
|
||||
|
||||
For bridging transactions, inbound refers to tokens bridged to the Flow blockchain, while outbound indicated tokens were sent from Flow to another (i.e. to Ethereum, BSC, etc.).
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/token_contract.md
Normal file
5
models/descriptions/token_contract.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs token_contract %}
|
||||
|
||||
The contract address for a token on the Flow blockchain.
|
||||
|
||||
{% enddocs %}
|
||||
267
models/silver/silver__bridge_blocto.sql
Normal file
267
models/silver/silver__bridge_blocto.sql
Normal file
@ -0,0 +1,267 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'delete+insert',
|
||||
cluster_by = ['_ingested_at::date'],
|
||||
unique_key = 'tx_id'
|
||||
) }}
|
||||
|
||||
WITH events AS (
|
||||
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
{{ ref('silver__events_final') }}
|
||||
|
||||
{% if is_incremental() %}
|
||||
WHERE
|
||||
_ingested_at :: DATE >= CURRENT_DATE -2
|
||||
{% endif %}
|
||||
),
|
||||
teleport_events AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
event_contract AS teleport_contract_fee,
|
||||
event_data :amount :: DOUBLE AS amount_fee,
|
||||
event_data :type :: NUMBER AS teleport_direction,
|
||||
_ingested_at
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
event_type = 'FeeCollected'
|
||||
AND event_contract LIKE '%Teleport%'
|
||||
),
|
||||
teleports_in AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
event_contract AS event_contract_teleport,
|
||||
event_data :amount :: DOUBLE AS amount_teleport,
|
||||
event_data :from AS from_teleport,
|
||||
STRTOK_TO_ARRAY(
|
||||
REPLACE(REPLACE(event_data :from :: STRING, '['), ']'),
|
||||
', '
|
||||
) :: ARRAY AS from_teleport_array,
|
||||
COALESCE(
|
||||
event_data :hash,
|
||||
event_data :txHash
|
||||
) :: STRING AS hash_teleport,
|
||||
_ingested_at
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
tx_id IN (
|
||||
SELECT
|
||||
tx_id
|
||||
FROM
|
||||
teleport_events
|
||||
WHERE
|
||||
teleport_direction = 1
|
||||
)
|
||||
AND event_index = 0
|
||||
AND event_contract LIKE '%Teleport%'
|
||||
AND event_type IN (
|
||||
'TokensTeleportedIn',
|
||||
'Unlocked'
|
||||
)
|
||||
AND from_teleport :: STRING NOT LIKE '%{\"ArrayType%'
|
||||
),
|
||||
deposits AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
event_contract,
|
||||
event_index,
|
||||
event_data :amount :: DOUBLE AS amount_deposits,
|
||||
ROW_NUMBER() over (
|
||||
PARTITION BY tx_id
|
||||
ORDER BY
|
||||
amount_deposits DESC
|
||||
) AS rn,
|
||||
event_data :to :: STRING AS to_deposits
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
tx_id IN (
|
||||
SELECT
|
||||
tx_id
|
||||
FROM
|
||||
teleports_in
|
||||
)
|
||||
AND event_type = 'TokensDeposited'
|
||||
ORDER BY
|
||||
tx_id,
|
||||
amount_deposits DESC
|
||||
),
|
||||
blocto_inbound AS (
|
||||
SELECT
|
||||
t.tx_id,
|
||||
f.block_timestamp,
|
||||
f.block_height,
|
||||
t.event_contract_teleport AS teleport_contract,
|
||||
d.event_contract AS token_contract,
|
||||
t.amount_teleport AS gross_amount,
|
||||
f.amount_fee,
|
||||
d.amount_deposits AS net_amount,
|
||||
d.to_deposits AS flow_wallet_address,
|
||||
f.teleport_direction,
|
||||
'blocto' AS bridge,
|
||||
f._ingested_at
|
||||
FROM
|
||||
teleports_in t
|
||||
LEFT JOIN deposits d USING (tx_id)
|
||||
LEFT JOIN teleport_events f USING (tx_id)
|
||||
WHERE
|
||||
d.rn = 1
|
||||
),
|
||||
teleports_out_withdraw AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
event_contract,
|
||||
event_data :amount :: DOUBLE AS amount_withdraw,
|
||||
event_data :from :: STRING AS from_withdraw
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
tx_id IN (
|
||||
SELECT
|
||||
tx_id
|
||||
FROM
|
||||
teleport_events
|
||||
WHERE
|
||||
teleport_direction = 0
|
||||
)
|
||||
AND event_index = 0
|
||||
),
|
||||
teleports_out AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
event_contract AS event_contract_teleport,
|
||||
event_data :amount :: DOUBLE AS amount_teleport,
|
||||
event_data :to AS to_teleport,
|
||||
STRTOK_TO_ARRAY(
|
||||
REPLACE(REPLACE(event_data :to :: STRING, '['), ']'),
|
||||
', '
|
||||
) :: ARRAY AS to_teleport_array
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
tx_id IN (
|
||||
SELECT
|
||||
tx_id
|
||||
FROM
|
||||
teleport_events
|
||||
WHERE
|
||||
teleport_direction = 0
|
||||
)
|
||||
AND event_type IN (
|
||||
'TokensTeleportedOut',
|
||||
'Locked'
|
||||
)
|
||||
),
|
||||
blocto_outbound AS (
|
||||
SELECT
|
||||
t.tx_id,
|
||||
f.block_timestamp,
|
||||
f.block_height,
|
||||
t.event_contract_teleport AS teleport_contract,
|
||||
w.event_contract AS token_contract,
|
||||
w.amount_withdraw AS gross_amount,
|
||||
f.amount_fee,
|
||||
t.amount_teleport AS net_amount,
|
||||
w.from_withdraw AS flow_wallet_address,
|
||||
f.teleport_direction,
|
||||
'blocto' AS bridge,
|
||||
f._ingested_at
|
||||
FROM
|
||||
teleports_out t
|
||||
LEFT JOIN teleports_out_withdraw w USING (tx_id)
|
||||
LEFT JOIN teleport_events f USING (tx_id)
|
||||
),
|
||||
tbl_union AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
teleport_contract,
|
||||
token_contract,
|
||||
gross_amount,
|
||||
amount_fee,
|
||||
net_amount,
|
||||
flow_wallet_address,
|
||||
teleport_direction,
|
||||
bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
blocto_inbound
|
||||
UNION
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
teleport_contract,
|
||||
token_contract,
|
||||
gross_amount,
|
||||
amount_fee,
|
||||
net_amount,
|
||||
flow_wallet_address,
|
||||
teleport_direction,
|
||||
bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
blocto_outbound
|
||||
),
|
||||
tele_labels AS (
|
||||
SELECT
|
||||
'A.04ee69443dedf0e4.TeleportCustody' AS teleport_contract,
|
||||
'Ethereum' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
'A.0ac14a822e54cc4e.TeleportCustodyBSC' AS teleport_contract,
|
||||
'BSC' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
'A.0ac14a822e54cc4e.TeleportCustodySolana' AS teleport_contract,
|
||||
'Solana' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
'A.475755d2c9dccc3a.TeleportedSportiumToken' AS teleport_contract,
|
||||
'Ethereum' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
'A.bd7e596b12e277df.TeleportCustody' AS teleport_contract,
|
||||
'Ethereum' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
'A.c2fa71c36fd5b840.TeleportCustodyBSC' AS teleport_contract,
|
||||
'BSC' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
'A.cfdd90d4a00f7b5b.TeleportedTetherToken' AS teleport_contract,
|
||||
'Ethereum' AS blockchain
|
||||
),
|
||||
FINAL AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
t.teleport_contract,
|
||||
token_contract,
|
||||
gross_amount,
|
||||
amount_fee,
|
||||
net_amount,
|
||||
flow_wallet_address,
|
||||
CASE
|
||||
WHEN teleport_direction = 0 THEN 'outbound'
|
||||
ELSE 'inbound'
|
||||
END AS teleport_direction,
|
||||
l.blockchain,
|
||||
bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
tbl_union t
|
||||
LEFT JOIN tele_labels l USING (teleport_contract)
|
||||
)
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
FINAL
|
||||
128
models/silver/silver__bridge_blocto.yml
Normal file
128
models/silver/silver__bridge_blocto.yml
Normal file
@ -0,0 +1,128 @@
|
||||
version: 2
|
||||
|
||||
models:
|
||||
- name: silver__bridge_blocto
|
||||
description: |-
|
||||
This table parses transactions where tokens are bridged to or from the Flow network via Blocto Teleport.
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- tx_id
|
||||
|
||||
columns:
|
||||
- name: tx_id
|
||||
description: "{{ doc('tx_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: block_timestamp
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 1
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
|
||||
- name: block_height
|
||||
description: "{{ doc('block_height') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
|
||||
- name: teleport_contract
|
||||
description: "{{ doc('teleport_contract') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: token_contract
|
||||
description: "{{ doc('token_contract') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: gross_amount
|
||||
description: "{{ doc('gross_amount') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- DOUBLE
|
||||
- FLOAT
|
||||
|
||||
- name: amount_fee
|
||||
description: "{{ doc('amount_fee') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- DOUBLE
|
||||
- FLOAT
|
||||
|
||||
- name: net_amount
|
||||
description: "{{ doc('net_amount') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- DOUBLE
|
||||
- FLOAT
|
||||
|
||||
- name: flow_wallet_address
|
||||
description: "{{ doc('flow_wallet_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: teleport_direction
|
||||
description: "{{ doc('teleport_direction') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: blockchain
|
||||
description: "{{ doc('blockchain') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: bridge
|
||||
description: "{{ doc('bridge') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: _ingested_at
|
||||
description: "{{ doc('_ingested_at') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
177
models/silver/silver__bridge_celer.sql
Normal file
177
models/silver/silver__bridge_celer.sql
Normal file
@ -0,0 +1,177 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'delete+insert',
|
||||
cluster_by = ['_ingested_at::date'],
|
||||
unique_key = 'tx_id'
|
||||
) }}
|
||||
|
||||
WITH events AS (
|
||||
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
{{ ref('silver__events_final') }}
|
||||
|
||||
{% if is_incremental() %}
|
||||
WHERE
|
||||
_ingested_at :: DATE >= CURRENT_DATE -2
|
||||
{% endif %}
|
||||
),
|
||||
cbridge_txs AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
tx_succeeded,
|
||||
event_index,
|
||||
event_contract,
|
||||
event_type,
|
||||
event_data,
|
||||
_ingested_at
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
event_contract = 'A.08dd120226ec2213.PegBridge'
|
||||
),
|
||||
inbound AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
event_contract AS bridge_contract,
|
||||
REPLACE(REPLACE(event_data :token :: STRING, '.Vault'), '"') AS token_contract,
|
||||
event_data :amount :: DOUBLE AS amount,
|
||||
event_data :receiver :: STRING AS flow_wallet_address,
|
||||
REPLACE(CONCAT('0x', event_data :depositor) :: STRING, '"') AS counterparty,
|
||||
event_data :refChId :: NUMBER AS chain_id,
|
||||
'inbound' AS direction,
|
||||
'cbridge' AS bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
tx_id IN (
|
||||
SELECT
|
||||
tx_id
|
||||
FROM
|
||||
cbridge_txs
|
||||
)
|
||||
AND event_type = 'Mint'
|
||||
),
|
||||
outbound AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
event_contract AS bridge_contract,
|
||||
REPLACE(REPLACE(event_data :token :: STRING, '.Vault'), '"') AS token_contract,
|
||||
event_data :amount :: DOUBLE AS amount,
|
||||
event_data :burner :: STRING AS flow_wallet_address,
|
||||
REPLACE(
|
||||
event_data :toAddr :: STRING,
|
||||
'"'
|
||||
) AS counterparty,
|
||||
event_data :toChain :: NUMBER AS chain_id,
|
||||
'outbound' AS direction,
|
||||
'cbridge' AS bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
events
|
||||
WHERE
|
||||
tx_id IN (
|
||||
SELECT
|
||||
tx_id
|
||||
FROM
|
||||
cbridge_txs
|
||||
)
|
||||
AND event_type = 'Burn'
|
||||
),
|
||||
tbl_union AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
bridge_contract,
|
||||
token_contract,
|
||||
amount,
|
||||
flow_wallet_address,
|
||||
counterparty,
|
||||
chain_id,
|
||||
direction,
|
||||
bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
inbound
|
||||
UNION
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
bridge_contract,
|
||||
token_contract,
|
||||
amount,
|
||||
flow_wallet_address,
|
||||
counterparty,
|
||||
chain_id,
|
||||
direction,
|
||||
bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
outbound
|
||||
),
|
||||
chain_ids AS (
|
||||
SELECT
|
||||
1 AS chain_id,
|
||||
'Ethereum' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
56 AS chain_id,
|
||||
'BSC' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
137 AS chain_id,
|
||||
'Polygon' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
250 AS chain_id,
|
||||
'Fantom' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
2222 AS chain_id,
|
||||
'Kava' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
9001 AS chain_id,
|
||||
'Evmos' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
43114 AS chain_id,
|
||||
'Avalanche' AS blockchain
|
||||
UNION
|
||||
SELECT
|
||||
12340001 AS chain_id,
|
||||
'Flow' AS blockchain
|
||||
),
|
||||
FINAL AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
block_height,
|
||||
bridge_contract,
|
||||
token_contract,
|
||||
amount,
|
||||
flow_wallet_address,
|
||||
counterparty,
|
||||
t.chain_id,
|
||||
l.blockchain,
|
||||
direction,
|
||||
bridge,
|
||||
_ingested_at
|
||||
FROM
|
||||
tbl_union t
|
||||
LEFT JOIN chain_ids l USING (chain_id)
|
||||
)
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
FINAL
|
||||
125
models/silver/silver__bridge_celer.yml
Normal file
125
models/silver/silver__bridge_celer.yml
Normal file
@ -0,0 +1,125 @@
|
||||
version: 2
|
||||
|
||||
models:
|
||||
- name: silver__bridge_celer
|
||||
description: |-
|
||||
This table parses transactions where tokens are bridged to or from the Flow network using the Celer cBridge.
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- tx_id
|
||||
|
||||
columns:
|
||||
- name: tx_id
|
||||
description: "{{ doc('tx_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: block_timestamp
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 1
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
|
||||
- name: block_height
|
||||
description: "{{ doc('block_height') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
|
||||
- name: bridge_contract
|
||||
description: "{{ doc('bridge_contract') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: token_contract
|
||||
description: "{{ doc('token_contract') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: amount
|
||||
description: "{{ doc('amount') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- DOUBLE
|
||||
- FLOAT
|
||||
|
||||
- name: flow_wallet_address
|
||||
description: "{{ doc('flow_wallet_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: counterparty
|
||||
description: "{{ doc('counterparty') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: chain_id
|
||||
description: "{{ doc('chain_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
|
||||
- name: blockchain
|
||||
description: "{{ doc('blockchain') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: direction
|
||||
description: "{{ doc('direction') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: bridge
|
||||
description: "{{ doc('bridge') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
|
||||
- name: _ingested_at
|
||||
description: "{{ doc('_ingested_at') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
Loading…
Reference in New Issue
Block a user