mirror of
https://github.com/FlipsideCrypto/cosmos-models.git
synced 2026-02-06 13:11:50 +00:00
bronze & silver ch1,2,3
This commit is contained in:
parent
319949a9f0
commit
c016b658ab
@ -28,7 +28,7 @@ jobs:
|
||||
uses: FlipsideCrypto/analytics-workflow-templates/.github/workflows/dbt_run_template.yml@main
|
||||
with:
|
||||
dbt_command: |
|
||||
dbt run -m models/bronze models/silver/core models/gold/core
|
||||
dbt run -m models/bronze models/silver/core models/gold/core --exclude models/bronze/genesis_backfill models/silver/core/genesis_backfill
|
||||
environment: workflow_prod
|
||||
warehouse: ${{ vars.WAREHOUSE }}
|
||||
secrets: inherit
|
||||
2
.github/workflows/dbt_test.yml
vendored
2
.github/workflows/dbt_test.yml
vendored
@ -27,7 +27,7 @@ jobs:
|
||||
uses: FlipsideCrypto/analytics-workflow-templates/.github/workflows/dbt_run_template.yml@main
|
||||
with:
|
||||
dbt_command: |
|
||||
dbt test -m models/bronze models/silver models/gold
|
||||
dbt test -m models/bronze models/silver models/gold --exclude models/bronze/genesis_backfill models/silver/core/genesis_backfill
|
||||
environment: workflow_prod
|
||||
warehouse: ${{ vars.WAREHOUSE }}
|
||||
secrets: inherit
|
||||
|
||||
@ -0,0 +1,11 @@
|
||||
{{ config (
|
||||
materialized = 'view'
|
||||
) }}
|
||||
|
||||
{% set model = this.identifier.split("_") [-1] %}
|
||||
{{ streamline_external_table_FR_query(
|
||||
model = 'blocks_ch1',
|
||||
partition_function = "CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 3), '_', 1) AS INTEGER)",
|
||||
partition_name = "_partition_by_block_id",
|
||||
unique_key = "block_number"
|
||||
) }}
|
||||
@ -0,0 +1,11 @@
|
||||
{{ config (
|
||||
materialized = 'view'
|
||||
) }}
|
||||
|
||||
{% set model = this.identifier.split("_") [-1] %}
|
||||
{{ streamline_external_table_FR_query(
|
||||
model = 'blocks_ch2',
|
||||
partition_function = "CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 3), '_', 1) AS INTEGER)",
|
||||
partition_name = "_partition_by_block_id",
|
||||
unique_key = "block_number"
|
||||
) }}
|
||||
@ -0,0 +1,11 @@
|
||||
{{ config (
|
||||
materialized = 'view'
|
||||
) }}
|
||||
|
||||
{% set model = this.identifier.split("_") [-1] %}
|
||||
{{ streamline_external_table_FR_query(
|
||||
model = 'blocks_ch3',
|
||||
partition_function = "CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 3), '_', 1) AS INTEGER)",
|
||||
partition_name = "_partition_by_block_id",
|
||||
unique_key = "block_number"
|
||||
) }}
|
||||
@ -0,0 +1,11 @@
|
||||
{{ config (
|
||||
materialized = 'view'
|
||||
) }}
|
||||
|
||||
{% set model = this.identifier.split("_") [-1] %}
|
||||
{{ streamline_external_table_FR_query(
|
||||
model = 'tx_search_ch1',
|
||||
partition_function = "CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 3), '_', 1) AS INTEGER)",
|
||||
partition_name = "_partition_by_block_id",
|
||||
unique_key = "block_number"
|
||||
) }}
|
||||
@ -0,0 +1,11 @@
|
||||
{{ config (
|
||||
materialized = 'view'
|
||||
) }}
|
||||
|
||||
{% set model = this.identifier.split("_") [-1] %}
|
||||
{{ streamline_external_table_FR_query(
|
||||
model = 'tx_search_ch2',
|
||||
partition_function = "CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 3), '_', 1) AS INTEGER)",
|
||||
partition_name = "_partition_by_block_id",
|
||||
unique_key = "block_number"
|
||||
) }}
|
||||
@ -0,0 +1,11 @@
|
||||
{{ config (
|
||||
materialized = 'view'
|
||||
) }}
|
||||
|
||||
{% set model = this.identifier.split("_") [-1] %}
|
||||
{{ streamline_external_table_FR_query(
|
||||
model = 'tx_search_ch3',
|
||||
partition_function = "CAST(SPLIT_PART(SPLIT_PART(file_name, '/', 3), '_', 1) AS INTEGER)",
|
||||
partition_name = "_partition_by_block_id",
|
||||
unique_key = "block_number"
|
||||
) }}
|
||||
61
models/silver/core/genesis_backfill/silver__blocks_ch1.sql
Normal file
61
models/silver/core/genesis_backfill/silver__blocks_ch1.sql
Normal file
@ -0,0 +1,61 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = ['block_timestamp::DATE']
|
||||
) }}
|
||||
|
||||
SELECT
|
||||
block_number AS block_id,
|
||||
COALESCE(
|
||||
DATA :result :block :header :time :: TIMESTAMP,
|
||||
DATA :block :header :time :: TIMESTAMP,
|
||||
DATA :result :block :header :timestamp :: TIMESTAMP,
|
||||
DATA :block :header :timestamp :: TIMESTAMP
|
||||
) AS block_timestamp,
|
||||
'cosmos' AS blockchain,
|
||||
COALESCE(
|
||||
DATA :result :block :header :chain_id :: STRING,
|
||||
DATA :block :header :chain_id :: STRING
|
||||
) AS chain_id,
|
||||
COALESCE(
|
||||
ARRAY_SIZE(
|
||||
DATA :result :block :data :txs
|
||||
) :: NUMBER,
|
||||
ARRAY_SIZE(
|
||||
DATA :block :data :txs
|
||||
) :: NUMBER
|
||||
) AS tx_count,
|
||||
COALESCE(
|
||||
DATA :result :block :header :proposer_address :: STRING,
|
||||
DATA :block :header :proposer_address :: STRING
|
||||
) AS proposer_address,
|
||||
COALESCE(
|
||||
DATA :result :block :header :validators_hash :: STRING,
|
||||
DATA :block :header :validators_hash :: STRING
|
||||
) AS validator_hash,
|
||||
COALESCE(
|
||||
DATA :result :block :header,
|
||||
DATA :block :header
|
||||
) AS header,
|
||||
concat_ws(
|
||||
'-',
|
||||
chain_id,
|
||||
block_id
|
||||
) AS _unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['_unique_key']
|
||||
) }} AS blocks_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
_inserted_timestamp :: timestamp_ntz AS _inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
{{ ref('bronze__streamline_FR_blocks_ch1') }}
|
||||
WHERE
|
||||
VALUE :data :error IS NULL
|
||||
AND DATA :error IS NULL
|
||||
AND DATA :result :begin_block_events IS NULL qualify ROW_NUMBER() over (
|
||||
PARTITION BY chain_id,
|
||||
block_id
|
||||
ORDER BY
|
||||
_inserted_timestamp DESC
|
||||
) = 1
|
||||
69
models/silver/core/genesis_backfill/silver__blocks_ch1.yml
Normal file
69
models/silver/core/genesis_backfill/silver__blocks_ch1.yml
Normal file
@ -0,0 +1,69 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__blocks_ch1
|
||||
description: Records of all blocks that have occurred on Cosmos hub v1, dating back to the genesis block. Block range is from 0 to 500042)
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- _UNIQUE_KEY
|
||||
- sequence_gaps:
|
||||
column_name: block_ID
|
||||
columns:
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: BLOCKCHAIN
|
||||
description: "{{ doc('blockchain') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: CHAIN_ID
|
||||
description: "{{ doc('chain_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: TX_COUNT
|
||||
description: "{{ doc('tx_count') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: PROPOSER_ADDRESS
|
||||
description: "{{ doc('proposer_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: VALIDATOR_HASH
|
||||
description: "{{ doc('validator_hash') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
|
||||
61
models/silver/core/genesis_backfill/silver__blocks_ch2.sql
Normal file
61
models/silver/core/genesis_backfill/silver__blocks_ch2.sql
Normal file
@ -0,0 +1,61 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = ['block_timestamp::DATE']
|
||||
) }}
|
||||
|
||||
SELECT
|
||||
block_number AS block_id,
|
||||
COALESCE(
|
||||
DATA :result :block :header :time :: TIMESTAMP,
|
||||
DATA :block :header :time :: TIMESTAMP,
|
||||
DATA :result :block :header :timestamp :: TIMESTAMP,
|
||||
DATA :block :header :timestamp :: TIMESTAMP
|
||||
) AS block_timestamp,
|
||||
'cosmos' AS blockchain,
|
||||
COALESCE(
|
||||
DATA :result :block :header :chain_id :: STRING,
|
||||
DATA :block :header :chain_id :: STRING
|
||||
) AS chain_id,
|
||||
COALESCE(
|
||||
ARRAY_SIZE(
|
||||
DATA :result :block :data :txs
|
||||
) :: NUMBER,
|
||||
ARRAY_SIZE(
|
||||
DATA :block :data :txs
|
||||
) :: NUMBER
|
||||
) AS tx_count,
|
||||
COALESCE(
|
||||
DATA :result :block :header :proposer_address :: STRING,
|
||||
DATA :block :header :proposer_address :: STRING
|
||||
) AS proposer_address,
|
||||
COALESCE(
|
||||
DATA :result :block :header :validators_hash :: STRING,
|
||||
DATA :block :header :validators_hash :: STRING
|
||||
) AS validator_hash,
|
||||
COALESCE(
|
||||
DATA :result :block :header,
|
||||
DATA :block :header
|
||||
) AS header,
|
||||
concat_ws(
|
||||
'-',
|
||||
chain_id,
|
||||
block_id
|
||||
) AS _unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['_unique_key']
|
||||
) }} AS blocks_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
_inserted_timestamp :: timestamp_ntz AS _inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
{{ ref('bronze__streamline_FR_blocks_ch2') }}
|
||||
WHERE
|
||||
VALUE :data :error IS NULL
|
||||
AND DATA :error IS NULL
|
||||
AND DATA :result :begin_block_events IS NULL qualify ROW_NUMBER() over (
|
||||
PARTITION BY chain_id,
|
||||
block_id
|
||||
ORDER BY
|
||||
_inserted_timestamp DESC
|
||||
) = 1
|
||||
69
models/silver/core/genesis_backfill/silver__blocks_ch2.yml
Normal file
69
models/silver/core/genesis_backfill/silver__blocks_ch2.yml
Normal file
@ -0,0 +1,69 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__blocks_ch2
|
||||
description: Block range is from 500,043 to 2,901,999)
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- _UNIQUE_KEY
|
||||
- sequence_gaps:
|
||||
column_name: block_ID
|
||||
columns:
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: BLOCKCHAIN
|
||||
description: "{{ doc('blockchain') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: CHAIN_ID
|
||||
description: "{{ doc('chain_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: TX_COUNT
|
||||
description: "{{ doc('tx_count') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: PROPOSER_ADDRESS
|
||||
description: "{{ doc('proposer_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: VALIDATOR_HASH
|
||||
description: "{{ doc('validator_hash') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
|
||||
61
models/silver/core/genesis_backfill/silver__blocks_ch3.sql
Normal file
61
models/silver/core/genesis_backfill/silver__blocks_ch3.sql
Normal file
@ -0,0 +1,61 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = ['block_timestamp::DATE']
|
||||
) }}
|
||||
|
||||
SELECT
|
||||
block_number AS block_id,
|
||||
COALESCE(
|
||||
DATA :result :block :header :time :: TIMESTAMP,
|
||||
DATA :block :header :time :: TIMESTAMP,
|
||||
DATA :result :block :header :timestamp :: TIMESTAMP,
|
||||
DATA :block :header :timestamp :: TIMESTAMP
|
||||
) AS block_timestamp,
|
||||
'cosmos' AS blockchain,
|
||||
COALESCE(
|
||||
DATA :result :block :header :chain_id :: STRING,
|
||||
DATA :block :header :chain_id :: STRING
|
||||
) AS chain_id,
|
||||
COALESCE(
|
||||
ARRAY_SIZE(
|
||||
DATA :result :block :data :txs
|
||||
) :: NUMBER,
|
||||
ARRAY_SIZE(
|
||||
DATA :block :data :txs
|
||||
) :: NUMBER
|
||||
) AS tx_count,
|
||||
COALESCE(
|
||||
DATA :result :block :header :proposer_address :: STRING,
|
||||
DATA :block :header :proposer_address :: STRING
|
||||
) AS proposer_address,
|
||||
COALESCE(
|
||||
DATA :result :block :header :validators_hash :: STRING,
|
||||
DATA :block :header :validators_hash :: STRING
|
||||
) AS validator_hash,
|
||||
COALESCE(
|
||||
DATA :result :block :header,
|
||||
DATA :block :header
|
||||
) AS header,
|
||||
concat_ws(
|
||||
'-',
|
||||
chain_id,
|
||||
block_id
|
||||
) AS _unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['_unique_key']
|
||||
) }} AS blocks_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
_inserted_timestamp :: timestamp_ntz AS _inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
{{ ref('bronze__streamline_FR_blocks_ch3') }}
|
||||
WHERE
|
||||
VALUE :data :error IS NULL
|
||||
AND DATA :error IS NULL
|
||||
AND DATA :result :begin_block_events IS NULL qualify ROW_NUMBER() over (
|
||||
PARTITION BY chain_id,
|
||||
block_id
|
||||
ORDER BY
|
||||
_inserted_timestamp DESC
|
||||
) = 1
|
||||
69
models/silver/core/genesis_backfill/silver__blocks_ch3.yml
Normal file
69
models/silver/core/genesis_backfill/silver__blocks_ch3.yml
Normal file
@ -0,0 +1,69 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__blocks_ch3
|
||||
description: Block range is from 2,902,000 and 5,200,790)
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- _UNIQUE_KEY
|
||||
- sequence_gaps:
|
||||
column_name: block_ID
|
||||
columns:
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: BLOCKCHAIN
|
||||
description: "{{ doc('blockchain') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: CHAIN_ID
|
||||
description: "{{ doc('chain_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: TX_COUNT
|
||||
description: "{{ doc('tx_count') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: PROPOSER_ADDRESS
|
||||
description: "{{ doc('proposer_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: VALIDATOR_HASH
|
||||
description: "{{ doc('validator_hash') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
|
||||
@ -0,0 +1,37 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = ['block_timestamp::DATE'],
|
||||
enabled = false
|
||||
) }}
|
||||
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
tx_succeeded,
|
||||
msg_group,
|
||||
msg_sub_group,
|
||||
msg_index,
|
||||
msg_type,
|
||||
0 AS attribute_index,
|
||||
TRY_BASE64_DECODE_STRING(
|
||||
msg :key :: STRING
|
||||
) AS attribute_key,
|
||||
TRY_BASE64_DECODE_STRING(
|
||||
msg :value :: STRING
|
||||
) AS attribute_value,
|
||||
concat_ws(
|
||||
'-',
|
||||
tx_id,
|
||||
msg_index,
|
||||
attribute_index
|
||||
) AS unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['tx_id','msg_index','attribute_index']
|
||||
) }} AS msg_attributes_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
_inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
{{ ref('silver__msgs_ch1') }} A
|
||||
140
models/silver/core/genesis_backfill/silver__msgs_ch1.sql
Normal file
140
models/silver/core/genesis_backfill/silver__msgs_ch1.sql
Normal file
@ -0,0 +1,140 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = ['block_timestamp::DATE'],
|
||||
enabled = false
|
||||
) }}
|
||||
|
||||
WITH base_msgs AS (
|
||||
|
||||
SELECT
|
||||
t.block_id,
|
||||
t.block_timestamp,
|
||||
t.tx_id,
|
||||
t.gas_used,
|
||||
t.gas_wanted,
|
||||
t.tx_succeeded,
|
||||
f.value AS msg,
|
||||
f.index :: INT AS msg_index,
|
||||
msg :type :: STRING AS msg_type,
|
||||
IFF(
|
||||
TRY_BASE64_DECODE_STRING(
|
||||
msg :attributes [0] :key :: STRING
|
||||
) = 'action',
|
||||
TRUE,
|
||||
FALSE
|
||||
) AS is_action,
|
||||
NULLIF(
|
||||
(conditional_true_event(is_action) over (PARTITION BY tx_id
|
||||
ORDER BY
|
||||
msg_index ASC) -1),
|
||||
-1
|
||||
) AS msg_group,
|
||||
IFF(
|
||||
TRY_BASE64_DECODE_STRING(
|
||||
msg :attributes [0] :key :: STRING
|
||||
) = 'module',
|
||||
TRUE,
|
||||
FALSE
|
||||
) AS is_module,
|
||||
TRY_BASE64_DECODE_STRING(
|
||||
msg :attributes [0] :key :: STRING
|
||||
) AS attribute_key,
|
||||
TRY_BASE64_DECODE_STRING(
|
||||
msg :attributes [0] :value :: STRING
|
||||
) AS attribute_value,
|
||||
t._inserted_timestamp
|
||||
FROM
|
||||
{{ ref(
|
||||
'silver__transactions_ch1'
|
||||
) }}
|
||||
t,
|
||||
LATERAL FLATTEN(
|
||||
input => msgs
|
||||
) f
|
||||
),
|
||||
exec_actions AS (
|
||||
SELECT
|
||||
DISTINCT tx_id,
|
||||
msg_group
|
||||
FROM
|
||||
base_msgs
|
||||
WHERE
|
||||
msg_type = 'message'
|
||||
AND attribute_key = 'action'
|
||||
AND LOWER(attribute_value) LIKE '%exec%'
|
||||
),
|
||||
GROUPING AS (
|
||||
SELECT
|
||||
base_msgs.tx_id,
|
||||
base_msgs.msg_index,
|
||||
RANK() over(
|
||||
PARTITION BY base_msgs.tx_id,
|
||||
base_msgs.msg_group
|
||||
ORDER BY
|
||||
base_msgs.msg_index
|
||||
) -1 AS msg_sub_group
|
||||
FROM
|
||||
base_msgs
|
||||
INNER JOIN exec_actions e
|
||||
ON base_msgs.tx_id = e.tx_id
|
||||
AND base_msgs.msg_group = e.msg_group
|
||||
WHERE
|
||||
base_msgs.is_module = 'TRUE'
|
||||
AND base_msgs.msg_type = 'message'
|
||||
),
|
||||
msgs AS (
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
A.tx_id,
|
||||
tx_succeeded,
|
||||
msg_group,
|
||||
CASE
|
||||
WHEN msg_group IS NULL THEN NULL
|
||||
ELSE COALESCE(
|
||||
LAST_VALUE(
|
||||
b.msg_sub_group ignore nulls
|
||||
) over(
|
||||
PARTITION BY A.tx_id,
|
||||
msg_group
|
||||
ORDER BY
|
||||
A.msg_index DESC rows unbounded preceding
|
||||
),
|
||||
0
|
||||
)
|
||||
END AS msg_sub_group,
|
||||
A.msg_index,
|
||||
msg_type,
|
||||
msg,
|
||||
concat_ws(
|
||||
'-',
|
||||
A.tx_id,
|
||||
A.msg_index
|
||||
) AS unique_key,
|
||||
_inserted_timestamp
|
||||
FROM
|
||||
base_msgs A
|
||||
LEFT JOIN GROUPING b
|
||||
ON A.tx_id = b.tx_id
|
||||
AND A.msg_index = b.msg_index
|
||||
)
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
tx_succeeded,
|
||||
msg_group,
|
||||
msg_sub_group,
|
||||
msg_index,
|
||||
msg_type,
|
||||
msg :: OBJECT AS msg,
|
||||
unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['tx_id','msg_index']
|
||||
) }} AS msgs_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
_inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
msgs
|
||||
88
models/silver/core/genesis_backfill/silver__msgs_ch1.yml
Normal file
88
models/silver/core/genesis_backfill/silver__msgs_ch1.yml
Normal file
@ -0,0 +1,88 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__msgs_ch1
|
||||
description: Records of all messages associated to transactions that have occurred on Cosmos, dating back to the genesis block.
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- TX_ID
|
||||
- MSG_INDEX
|
||||
columns:
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 1
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: TX_ID
|
||||
description: "{{ doc('tx_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: TX_SUCCEEDED
|
||||
description: "{{ doc('tx_succeeded') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- BOOLEAN
|
||||
- name: MSG_GROUP
|
||||
description: "{{ doc('msg_group') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: MSG_SUB_GROUP
|
||||
description: "{{ doc('msg_sub_group') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: MSG_INDEX
|
||||
description: "{{ doc('msg_index') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: MSG_TYPE
|
||||
description: "{{ doc('msg_type') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: MSG
|
||||
description: "{{ doc('msg') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- OBJECT
|
||||
- VARIENT
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
|
||||
@ -0,0 +1,67 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = 'block_timestamp::DATE'
|
||||
) }}
|
||||
|
||||
WITH base_transactions AS (
|
||||
|
||||
SELECT
|
||||
block_number AS block_id,
|
||||
t.value :hash :: STRING AS tx_id,
|
||||
t.value :tx_result :codespace AS codespace,
|
||||
COALESCE(
|
||||
t.value :tx_result :gas_used,
|
||||
t.value :tx_result :gasUsed
|
||||
) :: NUMBER AS gas_used,
|
||||
COALESCE(
|
||||
t.value :tx_result :gas_wanted,
|
||||
t.value :tx_result :gasWanted
|
||||
) :: NUMBER AS gas_wanted,
|
||||
CASE
|
||||
WHEN t.value :tx_result :code :: NUMBER = 0 THEN TRUE
|
||||
ELSE FALSE
|
||||
END AS tx_succeeded,
|
||||
t.value :tx_result :code :: NUMBER AS tx_code,
|
||||
COALESCE(
|
||||
t.value :tx_result :events,
|
||||
t.value :tx_result :tags
|
||||
) AS msgs,
|
||||
t.value :tx_result :log :: STRING AS tx_log,
|
||||
t.value AS full_tx,
|
||||
_inserted_timestamp :: timestamp_ntz AS _inserted_timestamp
|
||||
FROM
|
||||
{{ ref('bronze__streamline_FR_transactions_ch1') }},
|
||||
TABLE(FLATTEN(DATA :result :txs)) t
|
||||
)
|
||||
SELECT
|
||||
t.block_id,
|
||||
b.block_timestamp,
|
||||
tx_id,
|
||||
codespace,
|
||||
gas_used,
|
||||
gas_wanted,
|
||||
tx_succeeded,
|
||||
tx_code,
|
||||
msgs,
|
||||
tx_log,
|
||||
concat_ws(
|
||||
'-',
|
||||
t.block_id,
|
||||
tx_id
|
||||
) AS unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['tx_id']
|
||||
) }} AS transactions_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
t._inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
base_transactions t
|
||||
JOIN {{ ref('silver__blocks_ch1') }}
|
||||
b
|
||||
ON t.block_id = b.block_id qualify ROW_NUMBER() over (
|
||||
PARTITION BY tx_id
|
||||
ORDER BY
|
||||
t._inserted_timestamp DESC
|
||||
) = 1
|
||||
@ -0,0 +1,73 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__transactions_ch1
|
||||
columns:
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: TX_ID
|
||||
description: "{{ doc('tx_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
- name: CODESPACE
|
||||
description: "{{ doc('codespace') }}"
|
||||
- name: GAS_USED
|
||||
description: "{{ doc('gas_used') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: GAS_WANTED
|
||||
description: "{{ doc('gas_wanted') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: TX_SUCCEEDED
|
||||
description: "{{ doc('tx_succeeded') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- BOOLEAN
|
||||
- name: TX_CODE
|
||||
description: "{{ doc('tx_code') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: MSGS
|
||||
description: "{{ doc('msgs') }}"
|
||||
tests:
|
||||
- not_null:
|
||||
where: tx_code is null
|
||||
- name: TX_LOG
|
||||
description: "{{ doc('tx_log') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
@ -0,0 +1,68 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = 'block_timestamp::DATE'
|
||||
) }}
|
||||
|
||||
WITH base_transactions AS (
|
||||
|
||||
SELECT
|
||||
block_number AS block_id,
|
||||
t.value :hash :: STRING AS tx_id,
|
||||
t.value :tx_result :codespace AS codespace,
|
||||
COALESCE(
|
||||
t.value :tx_result :gas_used,
|
||||
t.value :tx_result :gasUsed
|
||||
) :: NUMBER AS gas_used,
|
||||
COALESCE(
|
||||
t.value :tx_result :gas_wanted,
|
||||
t.value :tx_result :gasWanted
|
||||
) :: NUMBER AS gas_wanted,
|
||||
CASE
|
||||
WHEN t.value :tx_result :code :: NUMBER = 0 THEN TRUE
|
||||
ELSE FALSE
|
||||
END AS tx_succeeded,
|
||||
t.value :tx_result :code :: NUMBER AS tx_code,
|
||||
COALESCE(
|
||||
t.value :tx_result :events,
|
||||
t.value :tx_result :tags
|
||||
) AS msgs,
|
||||
t.value :tx_result :log :: STRING AS tx_log,
|
||||
t.value AS full_tx,
|
||||
_inserted_timestamp :: timestamp_ntz AS _inserted_timestamp
|
||||
FROM
|
||||
{{ ref('bronze__streamline_FR_transactions_ch2') }},
|
||||
TABLE(FLATTEN(DATA :result :txs)) t
|
||||
)
|
||||
SELECT
|
||||
t.block_id,
|
||||
b.block_timestamp,
|
||||
tx_id,
|
||||
codespace,
|
||||
gas_used,
|
||||
gas_wanted,
|
||||
tx_succeeded,
|
||||
tx_code,
|
||||
msgs,
|
||||
tx_log,
|
||||
full_tx,
|
||||
concat_ws(
|
||||
'-',
|
||||
t.block_id,
|
||||
tx_id
|
||||
) AS unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['tx_id']
|
||||
) }} AS transactions_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
t._inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
base_transactions t
|
||||
JOIN {{ ref('silver__blocks_ch2') }}
|
||||
b
|
||||
ON t.block_id = b.block_id qualify ROW_NUMBER() over (
|
||||
PARTITION BY tx_id
|
||||
ORDER BY
|
||||
t._inserted_timestamp DESC
|
||||
) = 1
|
||||
@ -0,0 +1,73 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__transactions_ch2
|
||||
columns:
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: TX_ID
|
||||
description: "{{ doc('tx_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
- name: CODESPACE
|
||||
description: "{{ doc('codespace') }}"
|
||||
- name: GAS_USED
|
||||
description: "{{ doc('gas_used') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: GAS_WANTED
|
||||
description: "{{ doc('gas_wanted') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: TX_SUCCEEDED
|
||||
description: "{{ doc('tx_succeeded') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- BOOLEAN
|
||||
- name: TX_CODE
|
||||
description: "{{ doc('tx_code') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: MSGS
|
||||
description: "{{ doc('msgs') }}"
|
||||
tests:
|
||||
- not_null:
|
||||
where: tx_code is null
|
||||
- name: TX_LOG
|
||||
description: "{{ doc('tx_log') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
@ -0,0 +1,68 @@
|
||||
{{ config(
|
||||
materialized = 'table',
|
||||
cluster_by = 'block_timestamp::DATE'
|
||||
) }}
|
||||
|
||||
WITH base_transactions AS (
|
||||
|
||||
SELECT
|
||||
block_number AS block_id,
|
||||
t.value :hash :: STRING AS tx_id,
|
||||
t.value :tx_result :codespace AS codespace,
|
||||
COALESCE(
|
||||
t.value :tx_result :gas_used,
|
||||
t.value :tx_result :gasUsed
|
||||
) :: NUMBER AS gas_used,
|
||||
COALESCE(
|
||||
t.value :tx_result :gas_wanted,
|
||||
t.value :tx_result :gasWanted
|
||||
) :: NUMBER AS gas_wanted,
|
||||
CASE
|
||||
WHEN t.value :tx_result :code :: NUMBER = 0 THEN TRUE
|
||||
ELSE FALSE
|
||||
END AS tx_succeeded,
|
||||
t.value :tx_result :code :: NUMBER AS tx_code,
|
||||
COALESCE(
|
||||
t.value :tx_result :events,
|
||||
t.value :tx_result :tags
|
||||
) AS msgs,
|
||||
t.value :tx_result :log :: STRING AS tx_log,
|
||||
t.value AS full_tx,
|
||||
_inserted_timestamp :: timestamp_ntz AS _inserted_timestamp
|
||||
FROM
|
||||
{{ ref('bronze__streamline_FR_transactions_ch3') }},
|
||||
TABLE(FLATTEN(DATA :result :txs)) t
|
||||
)
|
||||
SELECT
|
||||
t.block_id,
|
||||
b.block_timestamp,
|
||||
tx_id,
|
||||
codespace,
|
||||
gas_used,
|
||||
gas_wanted,
|
||||
tx_succeeded,
|
||||
tx_code,
|
||||
msgs,
|
||||
tx_log,
|
||||
full_tx,
|
||||
concat_ws(
|
||||
'-',
|
||||
t.block_id,
|
||||
tx_id
|
||||
) AS unique_key,
|
||||
{{ dbt_utils.generate_surrogate_key(
|
||||
['tx_id']
|
||||
) }} AS transactions_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp,
|
||||
t._inserted_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
base_transactions t
|
||||
JOIN {{ ref('silver__blocks_ch3') }}
|
||||
b
|
||||
ON t.block_id = b.block_id qualify ROW_NUMBER() over (
|
||||
PARTITION BY tx_id
|
||||
ORDER BY
|
||||
t._inserted_timestamp DESC
|
||||
) = 1
|
||||
@ -0,0 +1,73 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__transactions_ch3
|
||||
columns:
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- name: TX_ID
|
||||
description: "{{ doc('tx_id') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
- name: CODESPACE
|
||||
description: "{{ doc('codespace') }}"
|
||||
- name: GAS_USED
|
||||
description: "{{ doc('gas_used') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: GAS_WANTED
|
||||
description: "{{ doc('gas_wanted') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: TX_SUCCEEDED
|
||||
description: "{{ doc('tx_succeeded') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- BOOLEAN
|
||||
- name: TX_CODE
|
||||
description: "{{ doc('tx_code') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- name: MSGS
|
||||
description: "{{ doc('msgs') }}"
|
||||
tests:
|
||||
- not_null:
|
||||
where: tx_code is null
|
||||
- name: TX_LOG
|
||||
description: "{{ doc('tx_log') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('inserted_timestamp') }}"
|
||||
tests:
|
||||
- not_null
|
||||
Loading…
Reference in New Issue
Block a user