diff --git a/macros/create_udfs.sql b/macros/create_udfs.sql index 0f9e86a..270becf 100644 --- a/macros/create_udfs.sql +++ b/macros/create_udfs.sql @@ -13,6 +13,8 @@ {{ create_udf_bulk_grpc() }} {{ create_udf_api() }} + {{ run_create_udf_array_disjunctive_union() }} + {% endset %} {% do run_query(sql) %} {{- fsc_utils.create_udfs() -}} diff --git a/macros/udf_array_disjunctive_union.sql b/macros/udf_array_disjunctive_union.sql new file mode 100644 index 0000000..eff5599 --- /dev/null +++ b/macros/udf_array_disjunctive_union.sql @@ -0,0 +1,10 @@ +{% macro run_create_udf_array_disjunctive_union() %} + {% set func_sql %} + CREATE + OR REPLACE FUNCTION {{ target.database }}.silver.udf_array_disjunctive_union( + a1 ARRAY, + a2 ARRAY + ) returns ARRAY LANGUAGE javascript AS 'return [...A1.filter(e => !A2.includes(e)),...A2.filter(e => !A1.includes(e))]'; +{% endset %} + {% do run_query(func_sql) %} +{% endmacro %} diff --git a/tests/tests__streamline_blocks_gap.sql b/tests/tests__streamline_blocks_gap.sql new file mode 100644 index 0000000..38f0837 --- /dev/null +++ b/tests/tests__streamline_blocks_gap.sql @@ -0,0 +1,45 @@ +{{ config( + severity = 'error', + tags = ['streamline_test'] +) }} + +WITH streamline_blocks AS ( + + SELECT + * + FROM + {{ ref('silver__streamline_blocks') }} + + {% if var( + 'TEST_RANGE', + False + ) %} + WHERE + block_height BETWEEN {{ var('start_height') }} + AND {{ var('end_height') }} + {% endif %} +), +determine_prior_block AS ( + SELECT + block_height, + block_id, + parent_id, + LAG(block_id) over ( + ORDER BY + block_height + ) AS prev_block_id, + LAG(block_height) over ( + ORDER BY + block_height + ) AS prev_block_height + FROM + streamline_blocks +) +SELECT + * +FROM + determine_prior_block +WHERE + prev_block_id != parent_id +ORDER BY + 1 diff --git a/tests/tests__streamline_collections_gap.sql b/tests/tests__streamline_collections_gap.sql new file mode 100644 index 0000000..62a7790 --- /dev/null +++ b/tests/tests__streamline_collections_gap.sql @@ -0,0 +1,70 @@ +{{ config( + severity = 'error', + tags = ['streamline_test'] +) }} + +WITH collections_expected AS ( + + SELECT + block_height, + collection_count, + ARRAY_AGG( + VALUE :collection_id :: STRING + ) AS collections_expected + FROM + {{ ref('silver__streamline_blocks') }}, + LATERAL FLATTEN(collection_guarantees) {% if var( + 'TEST_RANGE', + False + ) %} + WHERE + block_height BETWEEN {{ var('start_height') }} + AND {{ var('end_height') }} + {% endif %} + GROUP BY + 1, + 2 +), +collections_actual AS ( + SELECT + block_number AS block_height, + COUNT( + DISTINCT collection_id + ) AS collection_count, + ARRAY_AGG(collection_id) AS collections_actual + FROM + {{ ref('silver__streamline_collections') }} + + {% if var( + 'TEST_RANGE', + False + ) %} + WHERE + block_height BETWEEN {{ var('start_height') }} + AND {{ var('end_height') }} + {% endif %} + GROUP BY + 1 +) +SELECT + e.block_height, + e.collection_count AS expected, + COALESCE( + A.collection_count, + 0 + ) AS actual, + expected - actual AS difference, + SILVER.UDF_ARRAY_DISJUNCTIVE_UNION( + e.collections_expected, + COALESCE( + A.collections_actual, + ARRAY_CONSTRUCT() + ) + ) AS missing_collections +FROM + collections_expected e + LEFT JOIN collections_actual A USING(block_height) +WHERE + expected != actual +ORDER BY + 1 diff --git a/tests/tests__streamline_transaction_results_gap.sql b/tests/tests__streamline_transaction_results_gap.sql new file mode 100644 index 0000000..4fc3662 --- /dev/null +++ b/tests/tests__streamline_transaction_results_gap.sql @@ -0,0 +1,71 @@ +{{ config( + severity = 'error', + tags = ['streamline_test'] +) }} + +WITH results_expected AS ( + + SELECT + block_number AS block_height, + SUM(tx_count) AS txs_count, + ARRAY_AGG(collection_id) AS collections_expected, + array_union_agg(transaction_ids) AS txs_expected + FROM + {{ ref('silver__streamline_collections') }} + + {% if var( + 'TEST_RANGE', + False + ) %} + WHERE + block_height BETWEEN {{ var('start_height') }} + AND {{ var('end_height') }} + {% endif %} + GROUP BY + 1 +), +results_actual AS ( + SELECT + block_number AS block_height, + COUNT( + DISTINCT tx_id + ) AS txs_count, + ARRAY_AGG( + DISTINCT tx_id + ) AS txs_actual + FROM + {{ ref('silver__streamline_transaction_results') }} + + {% if var( + 'TEST_RANGE', + False + ) %} + WHERE + block_height BETWEEN {{ var('start_height') }} + AND {{ var('end_height') }} + {% endif %} + GROUP BY + 1 +) +SELECT + e.block_height, + e.txs_count AS expected, + COALESCE( + A.txs_count, + 0 + ) AS actual, + expected - actual AS difference, + SILVER.UDF_ARRAY_DISJUNCTIVE_UNION( + e.txs_expected, + COALESCE( + A.txs_actual, + array_construct() + ) + ) AS txs_missing +FROM + results_expected e + LEFT JOIN results_actual A USING(block_height) +WHERE + expected != actual +ORDER BY + 1 diff --git a/tests/tests__streamline_transactions_gap.sql b/tests/tests__streamline_transactions_gap.sql new file mode 100644 index 0000000..fec7b1c --- /dev/null +++ b/tests/tests__streamline_transactions_gap.sql @@ -0,0 +1,71 @@ +{{ config( + severity = 'error', + tags = ['streamline_test'] +) }} + +WITH transactions_expected AS ( + + SELECT + block_number AS block_height, + SUM(tx_count) AS txs_count, + ARRAY_AGG(collection_id) AS collections_expected, + ARRAY_UNION_AGG(transaction_ids) AS txs_expected + FROM + {{ ref('silver__streamline_collections') }} + + {% if var( + 'TEST_RANGE', + False + ) %} + WHERE + block_height BETWEEN {{ var('start_height') }} + AND {{ var('end_height') }} + {% endif %} + GROUP BY + 1 +), +transactions_actual AS ( + SELECT + block_number AS block_height, + COUNT( + DISTINCT tx_id + ) AS txs_count, + ARRAY_AGG( + DISTINCT tx_id + ) AS txs_actual + FROM + {{ ref('silver__streamline_transactions') }} + + {% if var( + 'TEST_RANGE', + False + ) %} + WHERE + block_height BETWEEN {{ var('start_height') }} + AND {{ var('end_height') }} + {% endif %} + GROUP BY + 1 +) +SELECT + e.block_height, + e.txs_count AS expected, + COALESCE( + A.txs_count, + 0 + ) AS actual, + expected - actual AS difference, + SILVER.UDF_ARRAY_DISJUNCTIVE_UNION( + e.txs_expected, + COALESCE( + A.txs_actual, + array_construct() + ) + ) AS txs_missing +FROM + transactions_expected e + LEFT JOIN transactions_actual A USING(block_height) +WHERE + expected != actual +ORDER BY + 1