mirror of
https://github.com/FlipsideCrypto/crosschain-models.git
synced 2026-02-06 15:36:46 +00:00
Ez_bridge_stats (#468)
* check * daily * update defi, add stats * desc * ov * add ink and core * rm space * add to gitignore and del file * .
This commit is contained in:
parent
768d1dad4b
commit
a7a3e80cb5
2
.gitignore
vendored
2
.gitignore
vendored
@ -3,7 +3,7 @@ dbt_modules/
|
||||
# newer versions of dbt use this directory instead of dbt_modules for test dependencies
|
||||
dbt_packages/
|
||||
logs/
|
||||
|
||||
package-lock.yml
|
||||
.user.yml
|
||||
|
||||
.venv/
|
||||
|
||||
@ -45,6 +45,8 @@ There is more information on how to use dbt docs in the last section of this doc
|
||||
|
||||
### Stats Tables (crosschain.stats)
|
||||
- [ez_activity_metrics_daily](https://flipsidecrypto.github.io/crosschain-models/#!/model/model.crosschain_models.stats__ez_activity_metrics_daily)
|
||||
- [ez_bridge_metrics_daily](https://flipsidecrypto.github.io/crosschain-models/#!/model/model.crosschain_models.stats__ez_bridge_metrics_daily)
|
||||
- [ez_bridge_protocol_metrics_daily](https://flipsidecrypto.github.io/crosschain-models/#!/model/model.crosschain_models.stats__ez_bridge__protocol_metrics_daily)
|
||||
- [ez_core_metrics_hourly](https://flipsidecrypto.github.io/crosschain-models/#!/model/model.crosschain_models.stats__ez_core_metrics_hourly)
|
||||
|
||||
### Cosmos Tables (crosschain.cosmos)
|
||||
|
||||
@ -23,6 +23,7 @@ SELECT
|
||||
amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
inserted_timestamp,
|
||||
modified_timestamp,
|
||||
complete_bridge_activity_id AS ez_bridge_activity_id
|
||||
|
||||
@ -36,6 +36,8 @@ models:
|
||||
description: '{{ doc("bridge_amount") }}'
|
||||
- name: AMOUNT_USD
|
||||
description: '{{ doc("bridge_amount_usd") }}'
|
||||
- name: TOKEN_IS_VERIFIED
|
||||
description: '{{ doc("prices_is_verified") }}'
|
||||
- name: EZ_BRIDGE_ACTIVITY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
- name: INSERTED_TIMESTAMP
|
||||
|
||||
188
models/gold/stats/stats__ez_bridge_metrics_daily.sql
Normal file
188
models/gold/stats/stats__ez_bridge_metrics_daily.sql
Normal file
@ -0,0 +1,188 @@
|
||||
-- depends_on: {{ ref('defi__ez_bridge_activity') }}
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'merge',
|
||||
merge_exclude_columns = ["inserted_timestamp"],
|
||||
unique_key = ['blockchain','block_date'],
|
||||
cluster_by = ['blockchain','block_date'],
|
||||
tags = ['metrics_daily']
|
||||
) }}
|
||||
|
||||
{% if execute %}
|
||||
|
||||
{% if is_incremental() %}
|
||||
{% set max_mod_query %}
|
||||
|
||||
SELECT
|
||||
MAX(modified_timestamp) modified_timestamp
|
||||
FROM
|
||||
{{ this }}
|
||||
|
||||
{% endset %}
|
||||
{% set max_mod = run_query(max_mod_query) [0] [0] %}
|
||||
{% if not max_mod or max_mod == 'None' %}
|
||||
{% set max_mod = '2099-01-01' %}
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
|
||||
--get the distinct blockchains & block dates that we are processing
|
||||
{% set dates_query %}
|
||||
CREATE
|
||||
OR REPLACE temporary TABLE silver.ez_bridge_metrics__intermediate_tmp AS
|
||||
SELECT
|
||||
DISTINCT source_chain,
|
||||
destination_chain,
|
||||
block_timestamp :: DATE AS block_date
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }}
|
||||
WHERE
|
||||
block_timestamp :: DATE < SYSDATE() :: DATE
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND modified_timestamp >= '{{ max_mod }}'
|
||||
AND block_timestamp :: DATE >= '2025-01-01'
|
||||
{% endif %}
|
||||
|
||||
{% endset %}
|
||||
{% do run_query(dates_query) %}
|
||||
--create a dynamic where clause with literal block dates
|
||||
{% set date_query %}
|
||||
SELECT
|
||||
DISTINCT block_date
|
||||
FROM
|
||||
silver.ez_bridge_metrics__intermediate_tmp {% endset %}
|
||||
{% set date_results = run_query(date_query) %}
|
||||
{% set date_filter %}
|
||||
A.block_timestamp :: DATE IN ({% if date_results.rows | length > 0 %}
|
||||
{% for date in date_results %}
|
||||
'{{ date[0] }}' {% if not loop.last %},
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
{% else %}
|
||||
'2099-01-01'
|
||||
{% endif %}) {% endset %}
|
||||
{% endif %}
|
||||
|
||||
WITH target_chains_cte AS (
|
||||
SELECT
|
||||
DISTINCT blockchain AS chain_name
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }}
|
||||
),
|
||||
ib AS (
|
||||
SELECT
|
||||
A.destination_chain AS blockchain,
|
||||
A.block_timestamp :: DATE AS block_date,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN token_is_verified THEN amount_usd
|
||||
ELSE 0
|
||||
END
|
||||
) AS total_inbound_volume,
|
||||
COUNT(
|
||||
DISTINCT destination_address
|
||||
) AS distinct_inbound_addresses,
|
||||
COUNT(
|
||||
DISTINCT tx_hash
|
||||
) AS distinct_inbound_transactions
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }} A
|
||||
JOIN target_chains_cte t
|
||||
ON t.chain_name = A.destination_chain
|
||||
JOIN (
|
||||
SELECT
|
||||
DISTINCT destination_chain,
|
||||
block_date
|
||||
FROM
|
||||
silver.ez_bridge_metrics__intermediate_tmp
|
||||
) b
|
||||
ON A.destination_chain = b.destination_chain
|
||||
AND A.block_timestamp :: DATE = b.block_date
|
||||
WHERE
|
||||
{{ date_filter }}
|
||||
GROUP BY
|
||||
A.destination_chain,
|
||||
A.block_timestamp :: DATE
|
||||
),
|
||||
ob AS (
|
||||
SELECT
|
||||
A.source_chain AS blockchain,
|
||||
A.block_timestamp :: DATE AS block_date,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN token_is_verified THEN amount_usd
|
||||
ELSE 0
|
||||
END
|
||||
) AS total_outbound_volume,
|
||||
COUNT(
|
||||
DISTINCT source_address
|
||||
) AS distinct_outbound_addresses,
|
||||
COUNT(
|
||||
DISTINCT tx_hash
|
||||
) AS distinct_outbound_transactions
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }} A
|
||||
JOIN target_chains_cte t
|
||||
ON t.chain_name = A.source_chain
|
||||
JOIN (
|
||||
SELECT
|
||||
DISTINCT source_chain,
|
||||
block_date
|
||||
FROM
|
||||
silver.ez_bridge_metrics__intermediate_tmp
|
||||
) b
|
||||
ON A.source_chain = b.source_chain
|
||||
AND A.block_timestamp :: DATE = b.block_date
|
||||
WHERE
|
||||
{{ date_filter }}
|
||||
GROUP BY
|
||||
A.source_chain,
|
||||
A.block_timestamp :: DATE
|
||||
),
|
||||
base AS (
|
||||
SELECT
|
||||
DISTINCT blockchain,
|
||||
block_date
|
||||
FROM
|
||||
ib
|
||||
UNION
|
||||
SELECT
|
||||
DISTINCT blockchain,
|
||||
block_date
|
||||
FROM
|
||||
ob
|
||||
)
|
||||
SELECT
|
||||
A.blockchain,
|
||||
A.block_date,
|
||||
ib.total_inbound_volume,
|
||||
ib.distinct_inbound_addresses,
|
||||
ib.distinct_inbound_transactions,
|
||||
ob.total_outbound_volume,
|
||||
ob.distinct_outbound_addresses,
|
||||
ob.distinct_outbound_transactions,
|
||||
COALESCE(
|
||||
ib.total_inbound_volume,
|
||||
0
|
||||
) - COALESCE(
|
||||
ob.total_outbound_volume,
|
||||
0
|
||||
) AS net_volume,
|
||||
COALESCE(
|
||||
ib.total_inbound_volume,
|
||||
0
|
||||
) + COALESCE(
|
||||
ob.total_outbound_volume,
|
||||
0
|
||||
) AS gross_volume,
|
||||
{{ dbt_utils.generate_surrogate_key(['a.blockchain',' A.block_date']) }} AS ez_bridge_metrics_daily_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp
|
||||
FROM
|
||||
base A
|
||||
LEFT JOIN ib
|
||||
ON A.blockchain = ib.blockchain
|
||||
AND A.block_date = ib.block_date
|
||||
LEFT JOIN ob
|
||||
ON A.blockchain = ob.blockchain
|
||||
AND A.block_date = ob.block_date
|
||||
58
models/gold/stats/stats__ez_bridge_metrics_daily.yml
Normal file
58
models/gold/stats/stats__ez_bridge_metrics_daily.yml
Normal file
@ -0,0 +1,58 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: stats__ez_bridge_metrics_daily
|
||||
description: "An aggregated daily view of cross-chain bridging metrics, including volume, distinct addresses and unique transactions grouped by blockchain."
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- BLOCK_DATE
|
||||
- BLOCKCHAIN
|
||||
|
||||
columns:
|
||||
- name: BLOCKCHAIN
|
||||
description: '{{ doc("blockchain_column") }}'
|
||||
- name: BLOCK_DATE
|
||||
description: '{{ doc("block_date") }}'
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 2
|
||||
- name: total_inbound_volume
|
||||
description: 'USD value of all verified tokens brought onto BLOCKCHAIN from any other chain via any bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_inbound_addresses
|
||||
description: '# unique addresses receiving bridged tokens onto BLOCKCHAIN from any other chain via any bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_inbound_transactions
|
||||
description: '# unique tx hashes for bridge tokens brought onto BLOCKCHAIN from any other chain via any bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: total_outbound_volume
|
||||
description: 'USD value of all tokens taken off BLOCKCHAIN to any other chain via any bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_outbound_addresses
|
||||
description: '# unique addresses sending tokens off BLOCKCHAIN to any other chain via any bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_outbound_transactions
|
||||
description: '# unique tx hashes for tokens taken off BLOCKCHAIN to any other chain via any bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: net_volume
|
||||
description: 'total_inbound_volume - total_outbound_volume'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: gross_volume
|
||||
description: 'total_inbound_volume + total_outbound_volume'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: EZ_BRIDGE_METRICS_DAILY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
197
models/gold/stats/stats__ez_bridge_protocol_metrics_daily.sql
Normal file
197
models/gold/stats/stats__ez_bridge_protocol_metrics_daily.sql
Normal file
@ -0,0 +1,197 @@
|
||||
-- depends_on: {{ ref('defi__ez_bridge_activity') }}
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'merge',
|
||||
merge_exclude_columns = ["inserted_timestamp"],
|
||||
unique_key = ['blockchain','block_date','protocol'],
|
||||
cluster_by = ['blockchain','block_date','protocol'],
|
||||
tags = ['metrics_daily']
|
||||
) }}
|
||||
|
||||
{% if execute %}
|
||||
|
||||
{% if is_incremental() %}
|
||||
{% set max_mod_query %}
|
||||
|
||||
SELECT
|
||||
MAX(modified_timestamp) modified_timestamp
|
||||
FROM
|
||||
{{ this }}
|
||||
|
||||
{% endset %}
|
||||
{% set max_mod = run_query(max_mod_query) [0] [0] %}
|
||||
{% if not max_mod or max_mod == 'None' %}
|
||||
{% set max_mod = '2099-01-01' %}
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
|
||||
--get the distinct blockchains & block dates that we are processing
|
||||
{% set dates_query %}
|
||||
CREATE
|
||||
OR REPLACE temporary TABLE silver.ez_bridge_metrics__intermediate_tmp AS
|
||||
SELECT
|
||||
DISTINCT source_chain,
|
||||
destination_chain,
|
||||
block_timestamp :: DATE AS block_date
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }}
|
||||
WHERE
|
||||
block_timestamp :: DATE < SYSDATE() :: DATE
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND modified_timestamp >= '{{ max_mod }}'
|
||||
AND block_timestamp :: DATE >= '2025-01-01'
|
||||
{% endif %}
|
||||
|
||||
{% endset %}
|
||||
{% do run_query(dates_query) %}
|
||||
--create a dynamic where clause with literal block dates
|
||||
{% set date_query %}
|
||||
SELECT
|
||||
DISTINCT block_date
|
||||
FROM
|
||||
silver.ez_bridge_metrics__intermediate_tmp {% endset %}
|
||||
{% set date_results = run_query(date_query) %}
|
||||
{% set date_filter %}
|
||||
A.block_timestamp :: DATE IN ({% if date_results.rows | length > 0 %}
|
||||
{% for date in date_results %}
|
||||
'{{ date[0] }}' {% if not loop.last %},
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
{% else %}
|
||||
'2099-01-01'
|
||||
{% endif %}) {% endset %}
|
||||
{% endif %}
|
||||
|
||||
WITH target_chains_cte AS (
|
||||
SELECT
|
||||
DISTINCT blockchain AS chain_name
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }}
|
||||
),
|
||||
ib AS (
|
||||
SELECT
|
||||
A.destination_chain AS blockchain,
|
||||
A.platform AS protocol,
|
||||
A.block_timestamp :: DATE AS block_date,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN token_is_verified THEN amount_usd
|
||||
ELSE 0
|
||||
END
|
||||
) AS total_inbound_volume,
|
||||
COUNT(
|
||||
DISTINCT destination_address
|
||||
) AS distinct_inbound_addresses,
|
||||
COUNT(
|
||||
DISTINCT tx_hash
|
||||
) AS distinct_inbound_transactions
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }} A
|
||||
JOIN target_chains_cte t
|
||||
ON t.chain_name = A.destination_chain
|
||||
JOIN (
|
||||
SELECT
|
||||
DISTINCT destination_chain,
|
||||
block_date
|
||||
FROM
|
||||
silver.ez_bridge_metrics__intermediate_tmp
|
||||
) b
|
||||
ON A.destination_chain = b.destination_chain
|
||||
AND A.block_timestamp :: DATE = b.block_date
|
||||
WHERE
|
||||
{{ date_filter }}
|
||||
GROUP BY
|
||||
A.destination_chain,
|
||||
A.platform,
|
||||
A.block_timestamp :: DATE
|
||||
),
|
||||
ob AS (
|
||||
SELECT
|
||||
A.source_chain AS blockchain,
|
||||
A.platform AS protocol,
|
||||
A.block_timestamp :: DATE AS block_date,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN token_is_verified THEN amount_usd
|
||||
ELSE 0
|
||||
END
|
||||
) AS total_outbound_volume,
|
||||
COUNT(
|
||||
DISTINCT source_address
|
||||
) AS distinct_outbound_addresses,
|
||||
COUNT(
|
||||
DISTINCT tx_hash
|
||||
) AS distinct_outbound_transactions
|
||||
FROM
|
||||
{{ ref('defi__ez_bridge_activity') }} A
|
||||
JOIN target_chains_cte t
|
||||
ON t.chain_name = A.source_chain
|
||||
JOIN (
|
||||
SELECT
|
||||
DISTINCT source_chain,
|
||||
block_date
|
||||
FROM
|
||||
silver.ez_bridge_metrics__intermediate_tmp
|
||||
) b
|
||||
ON A.source_chain = b.source_chain
|
||||
AND A.block_timestamp :: DATE = b.block_date
|
||||
WHERE
|
||||
{{ date_filter }}
|
||||
GROUP BY
|
||||
A.source_chain,
|
||||
A.platform,
|
||||
A.block_timestamp :: DATE
|
||||
),
|
||||
base AS (
|
||||
SELECT
|
||||
DISTINCT blockchain,
|
||||
block_date,
|
||||
protocol
|
||||
FROM
|
||||
ib
|
||||
UNION
|
||||
SELECT
|
||||
DISTINCT blockchain,
|
||||
block_date,
|
||||
protocol
|
||||
FROM
|
||||
ob
|
||||
)
|
||||
SELECT
|
||||
A.blockchain,
|
||||
A.protocol,
|
||||
A.block_date,
|
||||
ib.total_inbound_volume,
|
||||
ib.distinct_inbound_addresses,
|
||||
ib.distinct_inbound_transactions,
|
||||
ob.total_outbound_volume,
|
||||
ob.distinct_outbound_addresses,
|
||||
ob.distinct_outbound_transactions,
|
||||
COALESCE(
|
||||
ib.total_inbound_volume,
|
||||
0
|
||||
) - COALESCE(
|
||||
ob.total_outbound_volume,
|
||||
0
|
||||
) AS net_volume,
|
||||
COALESCE(
|
||||
ib.total_inbound_volume,
|
||||
0
|
||||
) + COALESCE(
|
||||
ob.total_outbound_volume,
|
||||
0
|
||||
) AS gross_volume,
|
||||
{{ dbt_utils.generate_surrogate_key(['a.blockchain','a.protocol','a.block_date']) }} AS ez_bridge_protocol_metrics_daily_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp
|
||||
FROM
|
||||
base A
|
||||
LEFT JOIN ib
|
||||
ON A.blockchain = ib.blockchain
|
||||
AND A.block_date = ib.block_date
|
||||
AND A.protocol = ib.protocol
|
||||
LEFT JOIN ob
|
||||
ON A.blockchain = ob.blockchain
|
||||
AND A.block_date = ob.block_date
|
||||
AND A.protocol = ob.protocol
|
||||
@ -0,0 +1,61 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: stats__ez_bridge_protocol_metrics_daily
|
||||
description: "An aggregated daily view of cross-chain bridging metrics, including volume, distinct addresses and unique transactions grouped by blockchain and bridge protocol."
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- BLOCK_DATE
|
||||
- BLOCKCHAIN
|
||||
- PROTOCOL
|
||||
|
||||
columns:
|
||||
- name: BLOCKCHAIN
|
||||
description: '{{ doc("blockchain_column") }}'
|
||||
- name: PROTOCOL
|
||||
description: '{{ doc("bridge_platform") }}'
|
||||
- name: BLOCK_DATE
|
||||
description: '{{ doc("block_date") }}'
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 2
|
||||
- name: total_inbound_volume
|
||||
description: 'USD value of all verified tokens brought onto BLOCKCHAIN from any other chain grouped by bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_inbound_addresses
|
||||
description: '# unique addresses receiving bridged tokens onto BLOCKCHAIN from any other chain grouped by bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_inbound_transactions
|
||||
description: '# unique tx hashes for bridge tokens brought onto BLOCKCHAIN from any other chain grouped by bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: total_outbound_volume
|
||||
description: 'USD value of all tokens taken off BLOCKCHAIN to any other chain grouped by bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_outbound_addresses
|
||||
description: '# unique addresses sending tokens off BLOCKCHAIN to any other chain grouped by bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: distinct_outbound_transactions
|
||||
description: '# unique tx hashes for tokens taken off BLOCKCHAIN to any other chain grouped by bridge protocol'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: net_volume
|
||||
description: 'total_inbound_volume - total_outbound_volume'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: gross_volume
|
||||
description: 'total_inbound_volume + total_outbound_volume'
|
||||
# tests:
|
||||
# - not_null
|
||||
- name: EZ_BRIDGE_METRICS_DAILY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
@ -1,7 +1,7 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'delete+insert',
|
||||
unique_key = '_unique_key',
|
||||
unique_key = ['block_timestamp::DATE','blockchain','_unique_key'],
|
||||
cluster_by = ['block_timestamp::DATE','blockchain','platform'],
|
||||
post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(tx_hash, bridge_address, source_address, destination_address, source_chain, destination_chain, token_address, token_symbol), SUBSTRING(bridge_address, source_address, destination_address, source_chain, destination_chain, token_address, token_symbol)",
|
||||
tags = ['hourly']
|
||||
@ -26,6 +26,7 @@ WITH ethereum AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -63,6 +64,7 @@ optimism AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -82,9 +84,9 @@ WHERE
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
blast AS (
|
||||
core AS (
|
||||
SELECT
|
||||
'blast' AS blockchain,
|
||||
'core' AS blockchain,
|
||||
platform,
|
||||
block_number,
|
||||
block_timestamp,
|
||||
@ -100,16 +102,17 @@ blast AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
FROM
|
||||
{{ source(
|
||||
'blast_defi',
|
||||
'core_defi',
|
||||
'ez_bridge_activity'
|
||||
) }}
|
||||
|
||||
{% if is_incremental() and 'blast' not in var('HEAL_MODELS') %}
|
||||
{% if is_incremental() and 'core' not in var('HEAL_MODELS') %}
|
||||
WHERE
|
||||
_inserted_timestamp >= (
|
||||
SELECT
|
||||
@ -137,6 +140,7 @@ avalanche AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -174,6 +178,7 @@ polygon AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -211,6 +216,7 @@ bsc AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -248,6 +254,7 @@ arbitrum AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -285,6 +292,7 @@ base AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -322,6 +330,7 @@ gnosis AS (
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
@ -341,6 +350,44 @@ WHERE
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
ink AS (
|
||||
SELECT
|
||||
'ink' AS blockchain,
|
||||
platform,
|
||||
block_number,
|
||||
block_timestamp,
|
||||
tx_hash,
|
||||
blockchain AS source_chain,
|
||||
destination_chain,
|
||||
bridge_address,
|
||||
sender AS source_address,
|
||||
destination_chain_receiver AS destination_address,
|
||||
'outbound' AS direction,
|
||||
token_address,
|
||||
token_symbol,
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
FROM
|
||||
{{ source(
|
||||
'ink_defi',
|
||||
'ez_bridge_activity'
|
||||
) }}
|
||||
|
||||
{% if is_incremental() and 'ink' not in var('HEAL_MODELS') %}
|
||||
WHERE
|
||||
_inserted_timestamp >= (
|
||||
SELECT
|
||||
MAX(_inserted_timestamp) - INTERVAL '{{ var("LOOKBACK", "24 hours") }}'
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
solana AS (
|
||||
SELECT
|
||||
'solana' AS blockchain,
|
||||
@ -348,36 +395,25 @@ solana AS (
|
||||
block_id AS block_number,
|
||||
block_timestamp,
|
||||
tx_id AS tx_hash,
|
||||
CASE
|
||||
WHEN direction = 'outbound' THEN 'solana'
|
||||
ELSE NULL
|
||||
END AS source_chain,
|
||||
CASE
|
||||
WHEN direction = 'inbound' THEN 'solana'
|
||||
ELSE NULL
|
||||
END AS destination_chain,
|
||||
source_chain,
|
||||
destination_chain,
|
||||
program_id AS bridge_address,
|
||||
CASE
|
||||
WHEN direction = 'outbound' THEN user_address
|
||||
ELSE NULL
|
||||
END AS source_address,
|
||||
CASE
|
||||
WHEN direction = 'inbound' THEN user_address
|
||||
ELSE NULL
|
||||
END AS destination_address,
|
||||
source_address,
|
||||
destination_address,
|
||||
direction,
|
||||
mint AS token_address,
|
||||
NULL AS token_symbol,
|
||||
symbol AS token_symbol,
|
||||
amount AS amount_raw,
|
||||
amount,
|
||||
NULL AS amount_usd,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['fact_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
FROM
|
||||
{{ source(
|
||||
'solana_defi',
|
||||
'fact_bridge_activity'
|
||||
'ez_bridge_activity'
|
||||
) }}
|
||||
|
||||
{% if is_incremental() and 'solana' not in var('HEAL_MODELS') %}
|
||||
@ -397,24 +433,25 @@ aptos AS (
|
||||
block_number,
|
||||
block_timestamp,
|
||||
tx_hash,
|
||||
LOWER(source_chain_name) AS source_chain,
|
||||
LOWER(destination_chain_name) AS destination_chain,
|
||||
LOWER(source_chain) AS source_chain,
|
||||
LOWER(destination_chain) AS destination_chain,
|
||||
bridge_address,
|
||||
sender AS source_address,
|
||||
receiver AS destination_address,
|
||||
direction,
|
||||
token_address,
|
||||
NULL AS token_symbol,
|
||||
symbol AS token_symbol,
|
||||
amount_unadj AS amount_raw,
|
||||
NULL AS amount,
|
||||
NULL AS amount_usd,
|
||||
amount AS amount,
|
||||
amount_in_usd AS amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['fact_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_number','platform']) }} AS _unique_key
|
||||
FROM
|
||||
{{ source(
|
||||
'aptos_defi',
|
||||
'fact_bridge_activity'
|
||||
'ez_bridge_activity'
|
||||
) }}
|
||||
|
||||
{% if is_incremental() and 'aptos' not in var('HEAL_MODELS') %}
|
||||
@ -444,7 +481,8 @@ near AS (
|
||||
symbol AS token_symbol,
|
||||
amount_unadj AS amount_raw,
|
||||
amount,
|
||||
NULL AS amount_usd,
|
||||
amount_usd,
|
||||
token_is_verified,
|
||||
modified_timestamp AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['ez_bridge_activity_id','blockchain']) }} AS complete_bridge_activity_id,
|
||||
complete_bridge_activity_id AS _unique_key
|
||||
@ -478,7 +516,7 @@ all_chains_bridge AS (
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
blast
|
||||
core
|
||||
UNION ALL
|
||||
SELECT
|
||||
*
|
||||
@ -510,6 +548,11 @@ all_chains_bridge AS (
|
||||
FROM
|
||||
gnosis
|
||||
UNION ALL
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
ink
|
||||
UNION ALL
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
@ -538,36 +581,11 @@ SELECT
|
||||
b.destination_address,
|
||||
b.direction,
|
||||
b.token_address,
|
||||
COALESCE(
|
||||
b.token_symbol,
|
||||
p.symbol
|
||||
) AS token_symbol,
|
||||
b.token_symbol,
|
||||
b.amount_raw,
|
||||
CASE
|
||||
WHEN b.blockchain = 'aptos'
|
||||
AND p.decimals IS NOT NULL THEN b.amount_raw / power(
|
||||
10,
|
||||
p.decimals
|
||||
)
|
||||
ELSE b.amount
|
||||
END AS amount,
|
||||
CASE
|
||||
WHEN b.blockchain IN (
|
||||
'ethereum',
|
||||
'optimism',
|
||||
'base',
|
||||
'arbitrum',
|
||||
'polygon',
|
||||
'bsc',
|
||||
'avalanche',
|
||||
'gnosis',
|
||||
'blast'
|
||||
) THEN b.amount_usd
|
||||
ELSE ROUND(
|
||||
p.price * amount,
|
||||
2
|
||||
)
|
||||
END AS amount_usd,
|
||||
amount,
|
||||
amount_usd,
|
||||
b.token_is_verified,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
b._inserted_timestamp,
|
||||
@ -575,11 +593,3 @@ SELECT
|
||||
complete_bridge_activity_id
|
||||
FROM
|
||||
all_chains_bridge b
|
||||
LEFT JOIN {{ ref('price__ez_prices_hourly') }}
|
||||
p
|
||||
ON b.blockchain = p.blockchain
|
||||
AND b.token_address = p.token_address
|
||||
AND DATE_TRUNC(
|
||||
'hour',
|
||||
b.block_timestamp
|
||||
) = p.hour
|
||||
|
||||
@ -46,6 +46,9 @@ models:
|
||||
- name: AMOUNT_RAW
|
||||
tests:
|
||||
- dbt_expectations.expect_column_to_exist
|
||||
- name: TOKEN_IS_VERIFIED
|
||||
tests:
|
||||
- dbt_expectations.expect_column_to_exist
|
||||
- name: COMPLETE_BRIDGE_ACTIVITY_ID
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
@ -52,7 +52,7 @@ sources:
|
||||
database: aptos
|
||||
schema: defi
|
||||
tables:
|
||||
- name: fact_bridge_activity
|
||||
- name: ez_bridge_activity
|
||||
|
||||
- name: aptos_observ
|
||||
database: aptos
|
||||
@ -515,6 +515,12 @@ sources:
|
||||
- name: dim_contracts
|
||||
- name: fact_transactions
|
||||
- name: ez_token_transfers
|
||||
|
||||
- name: core_defi
|
||||
database: core
|
||||
schema: defi
|
||||
tables:
|
||||
- name: ez_bridge_activity
|
||||
|
||||
- name: core_silver
|
||||
database: core
|
||||
@ -876,6 +882,12 @@ sources:
|
||||
- name: dim_contracts
|
||||
- name: fact_transactions
|
||||
- name: ez_token_transfers
|
||||
- name: ink_defi
|
||||
database: ink
|
||||
schema: defi
|
||||
tables:
|
||||
- name: ez_bridge_activity
|
||||
|
||||
- name: ink_silver
|
||||
database: ink
|
||||
schema: silver
|
||||
@ -1266,7 +1278,7 @@ sources:
|
||||
schema: defi
|
||||
tables:
|
||||
- name: fact_swaps
|
||||
- name: fact_bridge_activity
|
||||
- name: ez_bridge_activity
|
||||
|
||||
- name: solana_observ
|
||||
database: solana
|
||||
|
||||
@ -1,14 +0,0 @@
|
||||
packages:
|
||||
- package: calogica/dbt_expectations
|
||||
version: 0.8.0
|
||||
- package: dbt-labs/dbt_external_tables
|
||||
version: 0.8.0
|
||||
- package: dbt-labs/dbt_utils
|
||||
version: 1.0.0
|
||||
- git: https://github.com/FlipsideCrypto/fsc-utils.git
|
||||
revision: eb33ac727af26ebc8a8cc9711d4a6ebc3790a107
|
||||
- package: calogica/dbt_date
|
||||
version: 0.7.2
|
||||
- git: https://github.com/FlipsideCrypto/livequery-models.git
|
||||
revision: b024188be4e9c6bc00ed77797ebdc92d351d620e
|
||||
sha1_hash: a041a36ad8c4c5e042c054c10acf56e433869e05
|
||||
Loading…
Reference in New Issue
Block a user