mirror of
https://github.com/FlipsideCrypto/osmosis-models.git
synced 2026-02-06 13:57:16 +00:00
check in
This commit is contained in:
parent
4dd482fd86
commit
43fbc1cdcc
@ -42,6 +42,7 @@ models:
|
||||
vars:
|
||||
"dbt_date:time_zone": GMT
|
||||
"UPDATE_SNOWFLAKE_TAGS": TRUE
|
||||
OBSERV_FULL_TEST: FALSE
|
||||
|
||||
tests:
|
||||
+store_failures: true # all tests
|
||||
|
||||
@ -0,0 +1,113 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
full_refresh = false
|
||||
) }}
|
||||
|
||||
WITH source AS (
|
||||
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
LAG(
|
||||
block_id,
|
||||
1
|
||||
) over (
|
||||
ORDER BY
|
||||
block_id ASC
|
||||
) AS prev_BLOCK_ID
|
||||
FROM
|
||||
{{ ref('silver__blocks') }} A
|
||||
WHERE
|
||||
block_timestamp < DATEADD(HOUR, -14, SYSDATE())
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND (
|
||||
block_timestamp :: DATE >= (
|
||||
SELECT
|
||||
MAX(
|
||||
max_block_timestamp
|
||||
) :: DATE -3
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
OR ({% if var('OBSERV_FULL_TEST') %}
|
||||
block_id >= 0
|
||||
{% else %}
|
||||
block_id >= (
|
||||
SELECT
|
||||
MIN(VALUE) - 1
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
blocks_impacted_array {# JOIN A
|
||||
ON A.block_id = b.value #}
|
||||
FROM
|
||||
{{ this }}
|
||||
qualify ROW_NUMBER() over (
|
||||
ORDER BY
|
||||
test_timestamp DESC) = 1), LATERAL FLATTEN(input => blocks_impacted_array))
|
||||
{% endif %})
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
block_gen AS (
|
||||
SELECT
|
||||
_id AS block_id
|
||||
FROM
|
||||
{{ source(
|
||||
'crosschain_silver',
|
||||
'number_sequence'
|
||||
) }}
|
||||
)
|
||||
SELECT
|
||||
'blocks' AS test_name,
|
||||
MIN(
|
||||
b.block_id
|
||||
) AS min_block,
|
||||
MAX(
|
||||
b.block_id
|
||||
) AS max_block,
|
||||
MIN(
|
||||
b.block_timestamp
|
||||
) AS min_block_timestamp,
|
||||
MAX(
|
||||
b.block_timestamp
|
||||
) AS max_block_timestamp,
|
||||
COUNT(1) AS blocks_tested,
|
||||
COUNT(
|
||||
CASE
|
||||
WHEN C.block_id IS NOT NULL THEN A.block_id
|
||||
END
|
||||
) AS blocks_impacted_count,
|
||||
ARRAY_AGG(
|
||||
CASE
|
||||
WHEN C.block_id IS NOT NULL THEN A.block_id
|
||||
END
|
||||
) within GROUP (
|
||||
ORDER BY
|
||||
A.block_id
|
||||
) AS blocks_impacted_array,
|
||||
ARRAY_AGG(
|
||||
DISTINCT CASE
|
||||
WHEN C.block_id IS NOT NULL THEN OBJECT_CONSTRUCT(
|
||||
'prev_block_id',
|
||||
C.prev_block_id,
|
||||
'block_id',
|
||||
C.block_id
|
||||
)
|
||||
END
|
||||
) AS test_failure_details,
|
||||
CURRENT_TIMESTAMP AS test_timestamp
|
||||
FROM
|
||||
block_gen A
|
||||
LEFT JOIN source b
|
||||
ON A.block_id = b.block_id
|
||||
LEFT JOIN source C
|
||||
ON A.block_id > C.prev_BLOCK_ID
|
||||
AND A.block_id < C.block_id
|
||||
AND C.block_id - C.prev_BLOCK_ID <> 1
|
||||
WHERE
|
||||
COALESCE(
|
||||
b.block_id,
|
||||
C.block_id
|
||||
) IS NOT NULL
|
||||
@ -1,11 +1,11 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver_observability__block_gaps
|
||||
description: Records of all blocks block gaps with a timestamp the test was run
|
||||
- name: silver_observability__block_completeness
|
||||
description: Records of all blocks block gaps (missing blocks) with a timestamp the test was run
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- _INSERTED_TIMESTAMP
|
||||
- TEST_TIMESTAMP
|
||||
columns:
|
||||
- name: MIN_BLOCK
|
||||
description: The lowest block id in the test
|
||||
@ -34,33 +34,40 @@ models:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 1
|
||||
interval: 2
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: TOTAL_BLOCKS
|
||||
- name: BLOCKS_TESTED
|
||||
description: Count of blocks in the test
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- name: BLOCK_GAPS
|
||||
- name: BLOCKS_IMPACTED_COUNT
|
||||
description: Count of block gaps in the test
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- name: BLOCK_GAPS_DETAILS
|
||||
description: gap blocks
|
||||
- name: BLOCKS_IMPACTED_ARRAY
|
||||
description: Array of affected blocks
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- ARRAY
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
- name: TEST_FAILURE_DETAILS
|
||||
description: Array of details of the failure
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- ARRAY
|
||||
- name: TEST_TIMESTAMP
|
||||
description: When the test was run
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
@ -1,70 +0,0 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
full_refresh = false
|
||||
) }}
|
||||
|
||||
WITH source AS (
|
||||
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
LAG(
|
||||
block_id,
|
||||
1
|
||||
) over (
|
||||
ORDER BY
|
||||
block_id ASC
|
||||
) AS prev_BLOCK_ID
|
||||
FROM
|
||||
{{ ref('silver__blocks') }}
|
||||
|
||||
{% if is_incremental() %}
|
||||
WHERE
|
||||
(
|
||||
block_timestamp :: DATE >= (
|
||||
SELECT
|
||||
MAX(
|
||||
max_block_timestamp
|
||||
) :: DATE -3
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
OR (
|
||||
(
|
||||
SELECT
|
||||
block_gaps
|
||||
FROM
|
||||
{{ this }}
|
||||
qualify(ROW_NUMBER() over(
|
||||
ORDER BY
|
||||
max_block_timestamp DESC) = 1)
|
||||
) <> 0
|
||||
)
|
||||
)
|
||||
{% endif %}
|
||||
)
|
||||
SELECT
|
||||
MIN(block_id) AS min_block,
|
||||
MAX(block_id) AS max_block,
|
||||
MIN(block_timestamp) AS min_block_timestamp,
|
||||
MAX(block_timestamp) AS max_block_timestamp,
|
||||
COUNT(1) AS total_blocks,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN block_id - prev_BLOCK_ID <> 1 THEN 1
|
||||
ELSE 0
|
||||
END
|
||||
) AS block_gaps,
|
||||
ARRAY_AGG(
|
||||
CASE
|
||||
WHEN block_id - prev_BLOCK_ID <> 1 THEN OBJECT_CONSTRUCT(
|
||||
'prev_block_id',
|
||||
prev_block_id,
|
||||
'block_id',
|
||||
block_id
|
||||
)
|
||||
END
|
||||
) AS block_gaps_details,
|
||||
SYSDATE() AS _inserted_timestamp
|
||||
FROM
|
||||
source
|
||||
@ -32,6 +32,7 @@ sources:
|
||||
- name: asset_metadata_coin_gecko
|
||||
- name: hourly_prices_coin_market_cap
|
||||
- name: hourly_prices_coin_gecko
|
||||
- name: number_sequence
|
||||
- name: crosschain
|
||||
database: "{{ 'crosschain' if target.database == 'OSMOSIS' else 'crosschain_dev' }}"
|
||||
schema: core
|
||||
|
||||
Loading…
Reference in New Issue
Block a user