mirror of
https://github.com/FlipsideCrypto/movement-models.git
synced 2026-02-06 11:06:43 +00:00
commit
efed04f8e2
@ -25,7 +25,21 @@ There is more information on how to use dbt docs in the last section of this doc
|
||||
- [fact_transactions_block_metadata](#!/model/model.movement_models.core__fact_transactions_block_metadata)
|
||||
- [fact_transactions_state_checkpoint](#!/model/model.movement_models.core__fact_transactions_state_checkpoint)
|
||||
|
||||
## **Data Model Overview**
|
||||
### Price Tables (`movement`.`PRICE`.`<table_name>`)
|
||||
|
||||
**Dimension Tables:**
|
||||
- [price.dim_asset_metadata](https://flipsidecrypto.github.io/stellar-models/#!/model/model.movement_models.price__dim_asset_metadata)
|
||||
|
||||
**Fact Tables:**
|
||||
- [price.fact_prices_ohlc_hourly](https://flipsidecrypto.github.io/stellar-models/#!/model/model.movement_models.price__fact_prices_ohlc_hourly)
|
||||
|
||||
**Convenience Views:**
|
||||
- [price.ez_prices_hourly](https://flipsidecrypto.github.io/stellar-models/#!/model/model.movement_models.price__ez_prices_hourly)
|
||||
- [price.ez_asset_metadata](https://flipsidecrypto.github.io/stellar-models/#!/model/model.movement_models.price__ez_asset_metadata)
|
||||
|
||||
### Stats Tables (`stellar`.`STATS`.`<table_name>`)
|
||||
|
||||
- [stats.ez_core_metrics_hourly](https://flipsidecrypto.github.io/stellar-models/#!/model/model.movement_models.stats__ez_core_metrics_hourly)
|
||||
|
||||
The movement models are built a few different ways, but the core fact tables are built using three layers of sql models: **bronze, silver, and gold (or core).**
|
||||
|
||||
|
||||
37
models/gold/stats/gold_stats.yml
Normal file
37
models/gold/stats/gold_stats.yml
Normal file
@ -0,0 +1,37 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: stats__ez_core_metrics_hourly
|
||||
description: '{{ doc("ez_core_metrics_hourly_table_doc") }}'
|
||||
|
||||
columns:
|
||||
- name: BLOCK_TIMESTAMP_HOUR
|
||||
description: '{{ doc("block_timestamp_hour") }}'
|
||||
- name: BLOCK_NUMBER_MIN
|
||||
description: '{{ doc("block_number_min") }}'
|
||||
- name: BLOCK_NUMBER_MAX
|
||||
description: '{{ doc("block_number_max") }}'
|
||||
- name: BLOCK_COUNT
|
||||
description: '{{ doc("block_count") }}'
|
||||
- name: TRANSACTION_COUNT
|
||||
description: '{{ doc("transaction_count") }}'
|
||||
- name: TRANSACTION_COUNT_SUCCESS
|
||||
description: '{{ doc("transaction_count_success") }}'
|
||||
- name: TRANSACTION_COUNT_FAILED
|
||||
description: '{{ doc("transaction_count_failed") }}'
|
||||
- name: UNIQUE_SENDER_COUNT
|
||||
description: '{{ doc("unique_sender_count") }}'
|
||||
- name: UNIQUE_PAYLOAD_FUNCTION_COUNT
|
||||
description: '{{ doc("unique_payload_function_count") }}'
|
||||
- name: TOTAL_FEES_NATIVE
|
||||
description: '{{ doc("total_fees_native") }}'
|
||||
- name: TOTAL_FEES_USD
|
||||
description: '{{ doc("total_fees_usd") }}'
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: EZ_CORE_METRICS_HOURLY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
74
models/gold/stats/stats__ez_core_metrics_hourly.sql
Normal file
74
models/gold/stats/stats__ez_core_metrics_hourly.sql
Normal file
@ -0,0 +1,74 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'delete+insert',
|
||||
unique_key = "block_timestamp_hour",
|
||||
cluster_by = ['block_timestamp_hour::DATE'],
|
||||
meta ={ 'database_tags':{ 'table':{ 'PURPOSE': 'STATS, METRICS, CORE, HOURLY',
|
||||
} } },
|
||||
tags = ['noncore']
|
||||
) }}
|
||||
|
||||
-- depends_on: {{ ref('core__fact_transactions') }}
|
||||
|
||||
{% if execute %}
|
||||
|
||||
{% if is_incremental() %}
|
||||
{% set query %}
|
||||
|
||||
SELECT
|
||||
DATE_TRUNC('hour', MIN(block_timestamp)) AS block_timestamp_hour
|
||||
FROM
|
||||
{{ ref('core__fact_transactions') }}
|
||||
WHERE
|
||||
modified_timestamp >= (
|
||||
SELECT
|
||||
MAX(modified_timestamp)
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
{% endset %}
|
||||
{% set min_block_timestamp_hour = run_query(query).columns [0].values() [0] %}
|
||||
{% endif %}
|
||||
|
||||
{% if not min_block_timestamp_hour or min_block_timestamp_hour == 'None' %}
|
||||
{% set min_block_timestamp_hour = '2099-01-01' %}
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
|
||||
SELECT
|
||||
block_timestamp_hour,
|
||||
block_number_min,
|
||||
block_number_max,
|
||||
block_count,
|
||||
transaction_count,
|
||||
transaction_count_success,
|
||||
transaction_count_failed,
|
||||
unique_sender_count,
|
||||
unique_payload_function_count,
|
||||
total_fees AS total_fees_native,
|
||||
ROUND(
|
||||
(total_fees / pow(
|
||||
10,
|
||||
8
|
||||
)) * p.price,
|
||||
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('price__ez_prices_hourly') }}
|
||||
p
|
||||
ON s.block_timestamp_hour = p.hour
|
||||
AND p.is_native
|
||||
WHERE
|
||||
block_timestamp_hour < DATE_TRUNC('hour', CURRENT_TIMESTAMP)
|
||||
{% if is_incremental() %}
|
||||
AND
|
||||
block_timestamp_hour >= COALESCE(
|
||||
DATEADD('hour', -4, '{{ min_block_timestamp_hour }}'),
|
||||
'2025-01-01 00:00:00'
|
||||
)
|
||||
{% endif %}
|
||||
73
models/silver/stats/silver_stats.yml
Normal file
73
models/silver/stats/silver_stats.yml
Normal file
@ -0,0 +1,73 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver_stats__core_metrics_hourly
|
||||
config:
|
||||
contract:
|
||||
enforced: true
|
||||
tests:
|
||||
- dbt_utils.sequential_values:
|
||||
column_name: BLOCK_TIMESTAMP_HOUR
|
||||
interval: 1
|
||||
config:
|
||||
severity: error
|
||||
error_if: ">0"
|
||||
tags: ['test_recency']
|
||||
columns:
|
||||
- name: BLOCK_TIMESTAMP_HOUR
|
||||
data_type: TIMESTAMP_NTZ
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: BLOCK_NUMBER_MIN
|
||||
data_type: FLOAT
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: BLOCK_NUMBER_MAX
|
||||
data_type: FLOAT
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: BLOCK_COUNT
|
||||
data_type: NUMBER
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: TRANSACTION_COUNT
|
||||
data_type: NUMBER
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: TRANSACTION_COUNT_SUCCESS
|
||||
data_type: NUMBER
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: TRANSACTION_COUNT_FAILED
|
||||
data_type: NUMBER
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: UNIQUE_SENDER_COUNT
|
||||
data_type: NUMBER
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: UNIQUE_PAYLOAD_FUNCTION_COUNT
|
||||
data_type: NUMBER
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: TOTAL_FEES
|
||||
data_type: NUMBER
|
||||
tests:
|
||||
- not_null:
|
||||
tags: ['test_quality']
|
||||
- name: CORE_METRICS_HOURLY_ID
|
||||
data_type: VARCHAR
|
||||
- name: INSERTED_TIMESTAMP
|
||||
data_type: TIMESTAMP_NTZ
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
data_type: TIMESTAMP_NTZ
|
||||
- name: _INVOCATION_ID
|
||||
data_type: VARCHAR
|
||||
54
models/silver/stats/silver_stats__core_metrics_hourly.sql
Normal file
54
models/silver/stats/silver_stats__core_metrics_hourly.sql
Normal file
@ -0,0 +1,54 @@
|
||||
{{ config(
|
||||
materialized = 'view',
|
||||
persist_docs ={ "relation": true,
|
||||
"columns": true },
|
||||
meta ={ 'database_tags':{ 'table':{ 'PURPOSE': 'STATS, METRICS, CORE, HOURLY',
|
||||
} } },
|
||||
tags = ['noncore']
|
||||
) }}
|
||||
|
||||
SELECT
|
||||
DATE_TRUNC(
|
||||
'hour',
|
||||
block_timestamp
|
||||
) AS block_timestamp_hour,
|
||||
MIN(block_number) :: FLOAT AS block_number_min,
|
||||
MAX(block_number) :: FLOAT AS block_number_max,
|
||||
COUNT(
|
||||
DISTINCT block_number
|
||||
) AS block_count,
|
||||
COUNT(
|
||||
DISTINCT tx_hash
|
||||
) AS transaction_count,
|
||||
COUNT(
|
||||
DISTINCT CASE
|
||||
WHEN success THEN tx_hash
|
||||
END
|
||||
) AS transaction_count_success,
|
||||
COUNT(
|
||||
DISTINCT CASE
|
||||
WHEN NOT success THEN tx_hash
|
||||
END
|
||||
) AS transaction_count_failed,
|
||||
COUNT(
|
||||
DISTINCT sender
|
||||
) AS unique_sender_count,
|
||||
COUNT(
|
||||
DISTINCT payload_function
|
||||
) AS unique_payload_function_count,
|
||||
SUM(COALESCE(gas_unit_price,0) * gas_used) AS total_fees,
|
||||
{{ 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
|
||||
)
|
||||
GROUP BY
|
||||
1
|
||||
Loading…
Reference in New Issue
Block a user