mirror of
https://github.com/FlipsideCrypto/blast-models.git
synced 2026-02-06 15:26:45 +00:00
blast stats schema and docs (#40)
This commit is contained in:
parent
a1f3c4fbfe
commit
fd3b73f2df
@ -40,6 +40,9 @@ There is more information on how to use dbt docs in the last section of this doc
|
||||
- [ez_hourly_token_prices](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.price__ez_hourly_token_prices)
|
||||
- [dim_asset_metadata](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.price__dim_asset_metadata)
|
||||
- [ez_asset_metadata](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.price__ez_asset_metadata)
|
||||
|
||||
### Stats Tables (blast.stats)
|
||||
- [ez_core_metrics_hourly](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.stats__ez_core_metrics_hourly)
|
||||
|
||||
### Flipside Partner Tables (blast.partner_name)
|
||||
|
||||
|
||||
71
models/doc_descriptions/stats/evm_stats_core.md
Normal file
71
models/doc_descriptions/stats/evm_stats_core.md
Normal file
@ -0,0 +1,71 @@
|
||||
{% docs evm_ez_core_metrics_hourly_table_doc %}
|
||||
|
||||
A convenience table that aggregates block and transaction related metrics using various aggregate functions such as SUM, COUNT, MIN and MAX from the fact_transactions table, on an hourly basis.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_block_timestamp_hour %}
|
||||
|
||||
The hour of the timestamp of the block.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_block_number_min %}
|
||||
|
||||
The minimum block number in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_block_number_max %}
|
||||
|
||||
The maximum block number in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_block_count %}
|
||||
|
||||
The number of blocks in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_transaction_count %}
|
||||
|
||||
The number of transactions in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_transaction_count_success %}
|
||||
|
||||
The number of successful transactions in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_transaction_count_failed %}
|
||||
|
||||
The number of failed transactions in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_unique_from_count %}
|
||||
|
||||
The number of unique origin from addresses in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_unique_to_count %}
|
||||
|
||||
The number of unique origin to addresses in the hour.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_total_fees_native %}
|
||||
|
||||
The sum of all fees in the hour, in the native fee currency. Note, Snowflake's native SUM() function may limit decimal precision. To view precise transaction fee values, please use the `tx_fee_precise` column in `core.fact_transactions`.
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs evm_total_fees_usd %}
|
||||
|
||||
The sum of all fees in the hour, in USD, rounded to 2 decimal places.
|
||||
|
||||
{% enddocs %}
|
||||
37
models/gold/stats/stats__ez_core_metrics_hourly.sql
Normal file
37
models/gold/stats/stats__ez_core_metrics_hourly.sql
Normal file
@ -0,0 +1,37 @@
|
||||
{{ config(
|
||||
materialized = 'view',
|
||||
persist_docs ={ "relation": true,
|
||||
"columns": true },
|
||||
meta ={ 'database_tags':{ 'table':{ 'PURPOSE': 'STATS, METRICS, CORE, HOURLY',
|
||||
} } }
|
||||
) }}
|
||||
|
||||
SELECT
|
||||
block_timestamp_hour,
|
||||
block_number_min,
|
||||
block_number_max,
|
||||
block_count,
|
||||
transaction_count,
|
||||
transaction_count_success,
|
||||
transaction_count_failed,
|
||||
unique_from_count,
|
||||
unique_to_count,
|
||||
total_fees AS total_fees_native,
|
||||
ROUND(
|
||||
total_fees * LAST_VALUE(
|
||||
p.price ignore nulls
|
||||
) over (
|
||||
ORDER BY
|
||||
block_timestamp_hour rows unbounded preceding
|
||||
),
|
||||
2
|
||||
) AS total_fees_usd,
|
||||
core_metrics_hourly_id AS ez_core_metrics_hourly_id,
|
||||
s.inserted_timestamp AS inserted_timestamp,
|
||||
s.modified_timestamp AS modified_timestamp
|
||||
FROM
|
||||
{{ ref('silver_stats__core_metrics_hourly') }}
|
||||
s
|
||||
LEFT JOIN {{ ref('silver__hourly_prices_priority_eth') }}
|
||||
p
|
||||
ON s.block_timestamp_hour = p.hour
|
||||
34
models/gold/stats/stats__ez_core_metrics_hourly.yml
Normal file
34
models/gold/stats/stats__ez_core_metrics_hourly.yml
Normal file
@ -0,0 +1,34 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: stats__ez_core_metrics_hourly
|
||||
description: '{{ doc("evm_ez_core_metrics_hourly_table_doc") }}'
|
||||
|
||||
columns:
|
||||
- name: BLOCK_TIMESTAMP_HOUR
|
||||
description: '{{ doc("evm_block_timestamp_hour") }}'
|
||||
- name: BLOCK_NUMBER_MIN
|
||||
description: '{{ doc("evm_block_number_min") }}'
|
||||
- name: BLOCK_NUMBER_MAX
|
||||
description: '{{ doc("evm_block_number_max") }}'
|
||||
- name: BLOCK_COUNT
|
||||
description: '{{ doc("evm_block_count") }}'
|
||||
- name: TRANSACTION_COUNT
|
||||
description: '{{ doc("evm_transaction_count") }}'
|
||||
- name: TRANSACTION_COUNT_SUCCESS
|
||||
description: '{{ doc("evm_transaction_count_success") }}'
|
||||
- name: TRANSACTION_COUNT_FAILED
|
||||
description: '{{ doc("evm_transaction_count_failed") }}'
|
||||
- name: UNIQUE_FROM_COUNT
|
||||
description: '{{ doc("evm_unique_from_count") }}'
|
||||
- name: UNIQUE_TO_COUNT
|
||||
description: '{{ doc("evm_unique_to_count") }}'
|
||||
- name: TOTAL_FEES_NATIVE
|
||||
description: '{{ doc("evm_total_fees_native") }}'
|
||||
- name: TOTAL_FEES_USD
|
||||
description: '{{ doc("evm_total_fees_usd") }}'
|
||||
- name: EZ_CORE_METRICS_HOURLY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
80
models/silver/stats/silver_stats__core_metrics_hourly.sql
Normal file
80
models/silver/stats/silver_stats__core_metrics_hourly.sql
Normal file
@ -0,0 +1,80 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'delete+insert',
|
||||
unique_key = "block_timestamp_hour",
|
||||
cluster_by = ['block_timestamp_hour::DATE'],
|
||||
tags = ['curated']
|
||||
) }}
|
||||
/* run incremental timestamp value first then use it as a static value */
|
||||
{% if execute %}
|
||||
|
||||
{% if is_incremental() %}
|
||||
{% set query %}
|
||||
|
||||
SELECT
|
||||
MIN(DATE_TRUNC('hour', block_timestamp)) block_timestamp_hour
|
||||
FROM
|
||||
{{ ref('silver__transactions') }}
|
||||
WHERE
|
||||
_inserted_timestamp >= (
|
||||
SELECT
|
||||
MAX(_inserted_timestamp)
|
||||
FROM
|
||||
{{ this }}
|
||||
) {% endset %}
|
||||
{% set min_block_timestamp_hour = run_query(query).columns [0].values() [0] %}
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
SELECT
|
||||
DATE_TRUNC(
|
||||
'hour',
|
||||
block_timestamp
|
||||
) AS block_timestamp_hour,
|
||||
MIN(block_number) AS block_number_min,
|
||||
MAX(block_number) AS block_number_max,
|
||||
COUNT(
|
||||
DISTINCT block_number
|
||||
) AS block_count,
|
||||
COUNT(
|
||||
DISTINCT tx_hash
|
||||
) AS transaction_count,
|
||||
COUNT(
|
||||
DISTINCT CASE
|
||||
WHEN tx_success THEN tx_hash
|
||||
END
|
||||
) AS transaction_count_success,
|
||||
COUNT(
|
||||
DISTINCT CASE
|
||||
WHEN NOT tx_success THEN tx_hash
|
||||
END
|
||||
) AS transaction_count_failed,
|
||||
COUNT(
|
||||
DISTINCT from_address
|
||||
) AS unique_from_count,
|
||||
COUNT(
|
||||
DISTINCT to_address
|
||||
) AS unique_to_count,
|
||||
SUM(tx_fee_precise) AS total_fees,
|
||||
MAX(_inserted_timestamp) AS _inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['block_timestamp_hour']
|
||||
) }} AS core_metrics_hourly_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
{{ ref('silver__transactions') }}
|
||||
WHERE
|
||||
block_timestamp_hour < DATE_TRUNC(
|
||||
'hour',
|
||||
CURRENT_TIMESTAMP
|
||||
)
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND DATE_TRUNC(
|
||||
'hour',
|
||||
block_timestamp
|
||||
) >= '{{ min_block_timestamp_hour }}'
|
||||
{% endif %}
|
||||
GROUP BY
|
||||
1
|
||||
84
models/silver/stats/silver_stats__core_metrics_hourly.yml
Normal file
84
models/silver/stats/silver_stats__core_metrics_hourly.yml
Normal file
@ -0,0 +1,84 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver_stats__core_metrics_hourly
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- BLOCK_TIMESTAMP_HOUR
|
||||
columns:
|
||||
- name: BLOCK_TIMESTAMP_HOUR
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_LTZ
|
||||
- TIMESTAMP_NTZ
|
||||
- name: BLOCK_NUMBER_MIN
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: BLOCK_NUMBER_MAX
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: BLOCK_COUNT
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: TRANSACTION_COUNT
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: TRANSACTION_COUNT_SUCCESS
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: TRANSACTION_COUNT_FAILED
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: UNIQUE_FROM_COUNT
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: UNIQUE_TO_COUNT
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: TOTAL_FEES
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- DECIMAL
|
||||
- FLOAT
|
||||
- NUMBER
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
tests:
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 1
|
||||
Loading…
Reference in New Issue
Block a user