added transfers table

This commit is contained in:
D0R11 2022-10-21 01:45:18 +08:00
parent a6cd00564a
commit e0cde81f5e
10 changed files with 404 additions and 1 deletions

View File

@ -0,0 +1,30 @@
{{ config(
materialized = 'view',
secure = true
) }}
WITH transfers AS (
SELECT
*
FROM
{{ ref('silver__transfers') }}
)
SELECT
block_id,
block_timestamp,
tx_id,
transfer_id,
tx_succeeded,
chain_id,
message_value,
message_type,
message_index,
amount,
currency,
sender,
receiver,
blockchain,
transfer_type
FROM
final_table

View File

@ -0,0 +1,100 @@
version: 2
models:
- name: core__ez_transfers
description: |-
This table contains all the transfers that occurred in the Terra2 blockchain.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- transfer_id
columns:
- name: TRANSFER_ID
description: "{{ doc('transfer_id') }}"
tests:
- unique
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- STRING
- VARCHAR
- 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: 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_SUCCEEDED
description: "{{ doc('tx_succeeded') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- BOOLEAN
- name: CHAIN_ID
description: "{{ doc('chain_id') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- VARCHAR
- name: MESSAGE_INDEX
description: "{{ doc('message_index') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- NUMBER
- name: MESSAGE_TYPE
description: "{{ doc('message_type') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- VARCHAR
- name: MESSAGE_VALUE
description: "{{ doc('message_value') }}"
- name: AMOUNT
description: "{{ doc('amount') }}"
- name: CURRENCY
description: "{{ doc('currency') }}"
- name: SENDER
description: "{{ doc('sender') }}"
- name: RECEIVER
description: "{{ doc('receiver') }}"
- name: BLOCKCHAIN
description: "{{ doc('blockchain') }}"
- name: TRANSFER_TYPE
description: "{{ doc('transfer_type') }}"

View File

@ -2,4 +2,4 @@
The amount of currency for this action.
{% enddocs %}
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs currency %}
The currency of the amount for this transfer.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs receiver %}
The address of the receiver of this transfer.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs sender %}
The address of the sender, or authorizer, of this transfer.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs transfer_id %}
The unique key for each transfer.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs transfer_type %}
Determines whether the transfer is coming from one blockchain to another or vice versa.
{% enddocs %}

View File

@ -0,0 +1,142 @@
{{ config(
materialized = "incremental",
cluster_by = ["_inserted_timestamp"],
unique_key = "transfer_id",
) }}
WITH flattened_attributes AS (
SELECT
block_id,
block_timestamp,
tx_id,
tx_succeeded,
chain_id,
message_value,
message_type,
message_index,
REGEXP_SUBSTR(
key,
'[0-9]+'
) :: NUMBER AS key_index,
CASE
WHEN path LIKE 'amount%' THEN VALUE :: STRING
ELSE NULL
END AS amount,
CASE
WHEN path LIKE 'sender%' THEN VALUE :: STRING
ELSE NULL
END AS sender,
CASE
WHEN path LIKE 'currency%' THEN VALUE :: STRING
ELSE NULL
END AS currency,
CASE
WHEN path LIKE 'recipient%' THEN VALUE :: STRING
ELSE NULL
END AS receiver,
_ingested_at,
_inserted_timestamp
FROM
terra_dev.silver.messages,
LATERAL FLATTEN(
input => attributes :transfer,
outer => TRUE
)
WHERE
attributes :transfer IS NOT NULL
),
unpivoted_table AS (
SELECT
*
FROM
flattened_attributes unpivot(
VALUE for key IN (
sender,
amount,
currency,
receiver
)
)
),
pivoted_table AS (
SELECT
*
FROM
unpivoted_table pivot(MAX(VALUE) for key IN ('AMOUNT', 'CURRENCY', 'SENDER', 'RECEIVER')) AS p (
block_id,
block_timestamp,
tx_id,
tx_succeeded,
chain_id,
message_value,
message_type,
message_index,
key_index,
_ingested_at,
_inserted_timestamp,
amount,
currency,
sender,
receiver
)
),
final_table AS (
SELECT
block_id,
block_timestamp,
tx_id,
tx_succeeded,
chain_id,
message_value,
message_type,
message_index,
amount,
currency,
sender,
receiver,
ROW_NUMBER() over (
PARTITION BY tx_id
ORDER BY
block_timestamp
) - 1 AS INDEX,
CONCAT(
tx_id,
'_',
INDEX
) AS transfer_id,
REGEXP_SUBSTR(
message_type,
'(([^./]+)(/.\.|))',
1,
'1'
) AS blockchain,
CASE
WHEN message_type LIKE '/ibc%' THEN 'IBC_Transfer_In'
ELSE 'IBC_Transfer_Off'
END AS transfer_type,
_ingested_at,
_inserted_timestamp
FROM
pivoted_table
)
SELECT
block_id,
block_timestamp,
tx_id,
transfer_id,
tx_succeeded,
chain_id,
message_value,
message_type,
message_index,
amount,
currency,
sender,
receiver,
blockchain,
transfer_type,
_ingested_at,
_inserted_timestamp
FROM
final_table

View File

@ -0,0 +1,106 @@
version: 2
models:
- name: silver__transfers
description: |-
This table contains all the transfers that occurred in the Terra2 blockchain.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- transfer_id
columns:
- name: TRANSFER_ID
description: "{{ doc('transfer_id') }}"
tests:
- unique
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- STRING
- VARCHAR
- 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: 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_SUCCEEDED
description: "{{ doc('tx_succeeded') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- BOOLEAN
- name: CHAIN_ID
description: "{{ doc('chain_id') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- VARCHAR
- name: MESSAGE_INDEX
description: "{{ doc('message_index') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- NUMBER
- name: MESSAGE_TYPE
description: "{{ doc('message_type') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- VARCHAR
- name: MESSAGE_VALUE
description: "{{ doc('message_value') }}"
- name: AMOUNT
description: "{{ doc('amount') }}"
- name: CURRENCY
description: "{{ doc('currency') }}"
- name: SENDER
description: "{{ doc('sender') }}"
- name: RECEIVER
description: "{{ doc('receiver') }}"
- name: BLOCKCHAIN
description: "{{ doc('blockchain') }}"
- name: TRANSFER_TYPE
description: "{{ doc('transfer_type') }}"
- name: _INGESTED_AT
description: "{{ doc('_ingested_at') }}"
- name: _INSERTED_TIMESTAMP
description: "{{ doc('_inserted_timestamp') }}"