diff --git a/.github/workflows/dbt_test.yml b/.github/workflows/dbt_test.yml index 77db4e7..28741e9 100644 --- a/.github/workflows/dbt_test.yml +++ b/.github/workflows/dbt_test.yml @@ -4,7 +4,7 @@ run-name: dbt_test_scheduled on: workflow_dispatch: schedule: - - cron: '0 4 * * *' + - cron: '0 5 * * *' env: USE_VARS: "${{ vars.USE_VARS }}" diff --git a/models/bronze/axelscan/LQ/bronze__axelscan_gmp_stats_by_chains.sql b/models/bronze/axelscan/LQ/bronze__axelscan_gmp_stats_by_chains.sql new file mode 100644 index 0000000..0c9ca5e --- /dev/null +++ b/models/bronze/axelscan/LQ/bronze__axelscan_gmp_stats_by_chains.sql @@ -0,0 +1,106 @@ +{{ config( + materialized = 'incremental', + full_refresh = false, + tags = ['daily'] +) }} + +WITH dates_to_fetch AS ( + SELECT + A.date_day, + DATE_PART( + epoch_second, + A.date_day + ) AS from_ts, + DATE_PART( + epoch_second, + DATEADD( + DAY, + 1, + A.date_day + ) + ) - 1 AS to_ts + FROM + {{ source( + 'crosschain', + 'dim_dates' + ) }} A + WHERE + A.date_day >= '2025-01-01' + AND A.date_day < SYSDATE() :: DATE + +{% if is_incremental() %} +EXCEPT +SELECT + date_day, + from_ts, + to_ts +FROM + {{ this }} +{% endif %} +), +last_three_days AS ( + SELECT + A.date_day, + DATE_PART( + epoch_second, + A.date_day + ) AS from_ts, + DATE_PART( + epoch_second, + DATEADD( + DAY, + 1, + A.date_day + ) + ) - 1 AS to_ts + FROM + {{ source( + 'crosschain', + 'dim_dates' + ) }} A + WHERE + A.date_day >= SYSDATE() :: DATE - 3 + AND A.date_day < SYSDATE() :: DATE +), +date_params AS ( + SELECT DISTINCT + date_day, + from_ts, + to_ts + FROM ( + SELECT * FROM dates_to_fetch + UNION + SELECT * FROM last_three_days + ) + ORDER BY + 1 DESC + LIMIT + 20 +) +SELECT + date_day, + from_ts, + to_ts, + {{ target.database }}.live.udf_api( + 'POST', + 'https://api.axelarscan.io/gmp/GMPStatsByChains', + OBJECT_CONSTRUCT( + 'accept', + 'application/json', + 'content-type', + 'application/json' + ), + OBJECT_CONSTRUCT( + 'fromTime', + from_ts :: NUMBER, + 'toTime', + to_ts :: NUMBER + ) + ) AS resp, + SYSDATE() AS _inserted_timestamp +FROM + date_params +WHERE + ARRAY_SIZE( + resp :data :source_chains + ) > 0 diff --git a/models/bronze/axelscan/LQ/bronze__axelscan_transfer_stats_by_chains.sql b/models/bronze/axelscan/LQ/bronze__axelscan_transfer_stats_by_chains.sql new file mode 100644 index 0000000..3ae1898 --- /dev/null +++ b/models/bronze/axelscan/LQ/bronze__axelscan_transfer_stats_by_chains.sql @@ -0,0 +1,106 @@ +{{ config( + materialized = 'incremental', + full_refresh = false, + tags = ['daily'] +) }} + +WITH dates_to_fetch AS ( + SELECT + A.date_day, + DATE_PART( + epoch_second, + A.date_day + ) AS from_ts, + DATE_PART( + epoch_second, + DATEADD( + DAY, + 1, + A.date_day + ) + ) - 1 AS to_ts + FROM + {{ source( + 'crosschain', + 'dim_dates' + ) }} A + WHERE + A.date_day >= '2025-01-01' + AND A.date_day < SYSDATE() :: DATE + +{% if is_incremental() %} +EXCEPT +SELECT + date_day, + from_ts, + to_ts +FROM + {{ this }} +{% endif %} +), +last_three_days AS ( + SELECT + A.date_day, + DATE_PART( + epoch_second, + A.date_day + ) AS from_ts, + DATE_PART( + epoch_second, + DATEADD( + DAY, + 1, + A.date_day + ) + ) - 1 AS to_ts + FROM + {{ source( + 'crosschain', + 'dim_dates' + ) }} A + WHERE + A.date_day >= SYSDATE() :: DATE - 3 + AND A.date_day < SYSDATE() :: DATE +), +date_params AS ( + SELECT DISTINCT + date_day, + from_ts, + to_ts + FROM ( + SELECT * FROM dates_to_fetch + UNION + SELECT * FROM last_three_days + ) + ORDER BY + 1 DESC + LIMIT + 20 +) +SELECT + date_day, + from_ts, + to_ts, + {{ target.database }}.live.udf_api( + 'POST', + 'https://api.axelarscan.io/token/transfersStats', + OBJECT_CONSTRUCT( + 'accept', + 'application/json', + 'content-type', + 'application/json' + ), + OBJECT_CONSTRUCT( + 'fromTime', + from_ts :: NUMBER, + 'toTime', + to_ts :: NUMBER + ) + ) AS resp, + SYSDATE() AS _inserted_timestamp +FROM + date_params +WHERE + ARRAY_SIZE( + resp :data :data + ) > 0 diff --git a/models/gold/axelscan/axelscan__ez_bridge_metrics.sql b/models/gold/axelscan/axelscan__ez_bridge_metrics.sql new file mode 100644 index 0000000..2a5cd24 --- /dev/null +++ b/models/gold/axelscan/axelscan__ez_bridge_metrics.sql @@ -0,0 +1,134 @@ +{{ config( + materialized = 'incremental', + unique_key = ['day_utc'], + incremental_strategy = 'delete+insert', + tags = ['daily'] +) }} + +WITH gmp_stats AS ( + + SELECT + date_day, + b.value :key :: STRING AS source_chain, + C.value :key :: STRING AS destination_chain, + C.value :num_txs :: INT AS path_txs, + C.value :volume :: DECIMAL( + 18, + 2 + ) AS path_volume + FROM + {{ ref('bronze__axelscan_gmp_stats_by_chains') }}, + LATERAL FLATTEN( + resp :data :source_chains + ) b, + LATERAL FLATTEN( + b.value :destination_chains + ) C + +{% if is_incremental() %} +WHERE + date_day >= ( + SELECT + COALESCE(MAX(day_utc), '1970-01-01' :: DATE) - 3 + FROM + {{ this }}) + {% endif %} + ), + transfer_stats AS ( + SELECT + date_day, + b.value :source_chain :: STRING AS source_chain, + b.value :destination_chain :: STRING AS destination_chain, + SUM( + b.value :num_txs :: INT + ) AS path_txs, + SUM(b.value :volume :: DECIMAL(18, 2)) AS path_volume + FROM + {{ ref('bronze__axelscan_transfer_stats_by_chains') }}, + LATERAL FLATTEN( + resp :data :data + ) b + +{% if is_incremental() %} +WHERE + date_day >= ( + SELECT + COALESCE(MAX(day_utc), '1970-01-01' :: DATE) - 3 + FROM + {{ this }}) + {% endif %} + GROUP BY + ALL + ), + combined AS ( + SELECT + COALESCE( + g.source_chain, + t.source_chain + ) AS source_blockchain, + COALESCE( + g.destination_chain, + t.destination_chain + ) AS destination_blockchain, + COALESCE( + g.date_day, + t.date_day + ) AS day_utc, + COALESCE( + g.path_txs, + 0 + ) AS gmp_num_txs, + COALESCE( + g.path_volume, + 0 + ) AS gmp_volume_usd, + COALESCE( + t.path_txs, + 0 + ) AS transfers_num_txs, + COALESCE( + t.path_volume, + 0 + ) AS transfers_volume_usd + FROM + gmp_stats g full + OUTER JOIN transfer_stats t + ON g.date_day = t.date_day + AND g.source_chain = t.source_chain + AND g.destination_chain = t.destination_chain + ) +SELECT + source_blockchain, + destination_blockchain, + day_utc, + COALESCE( + gmp_num_txs + transfers_num_txs, + 0 + ) AS num_txs, + COALESCE( + gmp_volume_usd + transfers_volume_usd, + 0 + ) AS volume_usd, + COALESCE( + gmp_num_txs, + 0 + ) AS gmp_num_txs, + COALESCE( + gmp_volume_usd, + 0 + ) AS gmp_volume_usd, + COALESCE( + transfers_num_txs, + 0 + ) AS transfers_num_txs, + COALESCE( + transfers_volume_usd, + 0 + ) AS transfers_volume_usd, + {{ dbt_utils.generate_surrogate_key( + ['source_blockchain', 'destination_blockchain', 'day_utc'] + ) }} AS ez_bridge_metrics_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp +FROM + combined diff --git a/models/gold/axelscan/axelscan__ez_bridge_metrics.yml b/models/gold/axelscan/axelscan__ez_bridge_metrics.yml new file mode 100644 index 0000000..b0e45f8 --- /dev/null +++ b/models/gold/axelscan/axelscan__ez_bridge_metrics.yml @@ -0,0 +1,34 @@ +version: 2 + +models: + - name: axelscan__ez_bridge_metrics + description: "Combined bridge metrics from both GMP and transfers, aggregated by source chain, destination chain, and day. All null values default to 0." + columns: + - name: bridge_metrics_id + description: "Surrogate key generated from source_blockchain, destination_blockchain, and day_utc" + - name: source_blockchain + description: "Source blockchain for the bridge transaction" + - name: destination_blockchain + description: "Destination blockchain for the bridge transaction" + - name: day_utc + description: "Date of the transactions (UTC)" + tests: + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: hour + interval: 12 + - name: num_txs + description: "Total number of transactions (GMP + Transfers)" + - name: volume_usd + description: "Total volume in USD (GMP + Transfers)" + - name: gmp_num_txs + description: "Number of GMP transactions" + - name: gmp_volume_usd + description: "Volume of GMP transactions in USD" + - name: transfers_num_txs + description: "Number of transfer transactions" + - name: transfers_volume_usd + description: "Volume of transfer transactions in USD" + - name: inserted_timestamp + description: "Timestamp when the record was inserted" + - name: modified_timestamp + description: "Timestamp when the record was last modified"