An 1245 silver swaps osmo (#14)

* swaps model - successful swaps only

* join changes

* changed join to allow tokens that are not available in labels table

* added decimal column

* added in descriptions
This commit is contained in:
Jessica Huhnke 2022-05-12 15:00:01 -05:00 committed by GitHub
parent 2322c48633
commit 04e6eab89a
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
9 changed files with 239 additions and 0 deletions

View File

@ -0,0 +1,5 @@
{% docs swap_from_amount %}
The amount that the user sent to be swapped for another currency.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs swap_from_currency %}
The currency that the user sent to be swapped for another currency.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs swap_from_decimal %}
Divide the swap_from_amount by POW(10, swap_from_decimal) to get the amount the user swapped.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs swap_to_amount %}
The amount that the user sent to be swapped for another currency.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs swap_to_currency %}
The currency that the user sent to be swapped for another currency.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs swap_to_decimal %}
Divide the swap_to_amount by POW(10, swap_to_decimal) to get the amount the user received.
{% enddocs %}

View File

@ -0,0 +1,5 @@
{% docs trader %}
The wallet address of the individual who initiated the swap.
{% enddocs %}

View File

@ -0,0 +1,130 @@
{{ config(
materialized = 'incremental',
unique_key = "tx_id",
incremental_strategy = 'delete+insert',
cluster_by = ['_ingested_at::DATE'],
) }}
WITH message_indexes AS (
SELECT
tx_id,
attribute_key,
min(msg_index) as min_index,
max(msg_index) as max_index
FROM {{ ref('silver__msg_attributes') }}
WHERE msg_type = 'token_swapped'
AND (attribute_key = 'tokens_in' OR attribute_key = 'tokens_out')
{% if is_incremental() %}
AND _ingested_at :: DATE >= CURRENT_DATE - 2
{% endif %}
GROUP BY tx_id, attribute_key
),
tokens_in AS (
SELECT
t.tx_id,
split_part(TRIM(REGEXP_REPLACE(attribute_value, '[^[:digit:]]', ' ')), ' ', 0) AS swap_from_amount,
right(attribute_value, length(attribute_value) - length(split_part(TRIM(REGEXP_REPLACE(attribute_value, '[^[:digit:]]', ' ')), ' ', 0))) AS swap_from_currency,
l.raw_metadata[1]:exponent AS swap_from_decimal
FROM {{ ref('silver__msg_attributes') }} t
LEFT OUTER JOIN message_indexes m
ON t.tx_id = m.tx_id and t.attribute_key = m.attribute_key
LEFT OUTER JOIN {{ ref('silver__asset_metadata') }} l
ON right(attribute_value, length(attribute_value) - length(split_part(TRIM(REGEXP_REPLACE(attribute_value, '[^[:digit:]]', ' ')), ' ', 0))) = l.address
WHERE msg_type = 'token_swapped'
AND t.attribute_key = 'tokens_in'
AND t.msg_index = m.min_index
{% if is_incremental() %}
AND _ingested_at :: DATE >= CURRENT_DATE - 2
{% endif %}
),
tokens_out AS (
SELECT
t.tx_id,
split_part(TRIM(REGEXP_REPLACE(attribute_value, '[^[:digit:]]', ' ')), ' ', 0) AS swap_to_amount,
right(attribute_value, length(attribute_value) - length(split_part(TRIM(REGEXP_REPLACE(attribute_value, '[^[:digit:]]', ' ')), ' ', 0))) AS swap_to_currency,
l.raw_metadata[1]:exponent AS swap_to_decimal
FROM {{ ref('silver__msg_attributes') }} t
LEFT OUTER JOIN message_indexes m
ON t.tx_id = m.tx_id and t.attribute_key = m.attribute_key
LEFT OUTER JOIN {{ ref('silver__asset_metadata') }} l
ON right(attribute_value, length(attribute_value) - length(split_part(TRIM(REGEXP_REPLACE(attribute_value, '[^[:digit:]]', ' ')), ' ', 0))) = l.address
WHERE msg_type = 'token_swapped'
AND t.attribute_key = 'tokens_out'
AND t.msg_index = m.max_index
{% if is_incremental() %}
AND _ingested_at :: DATE >= CURRENT_DATE - 2
{% endif %}
),
pools AS (
SELECT
tx_id,
array_agg(attribute_value :: INTEGER) as pool_ids
FROM {{ ref('silver__msg_attributes') }}
WHERE attribute_key = 'pool_id'
{% if is_incremental() %}
AND _ingested_at :: DATE >= CURRENT_DATE - 2
{% endif %}
GROUP BY tx_id
),
trader AS (
SELECT
tx_id,
split_part(attribute_value, '/', 0) as trader
FROM {{ ref('silver__msg_attributes') }}
WHERE attribute_key = 'acc_seq'
{% if is_incremental() %}
AND _ingested_at :: DATE >= CURRENT_DATE - 2
{% endif %}
)
SELECT
t.block_id,
t.block_timestamp,
t.blockchain,
t.chain_id,
t.tx_id,
t.tx_status,
s.trader,
f.swap_from_amount AS swap_from_amount,
f.swap_from_currency,
f.swap_from_decimal,
tt.swap_to_amount,
tt.swap_to_currency,
tt.swap_to_decimal,
pool_ids,
t._ingested_at
FROM tokens_in f
LEFT OUTER JOIN {{ ref('silver__transactions') }} t
ON f.tx_id = t.tx_id
INNER JOIN tokens_out tt
ON f.tx_id = tt.tx_id
INNER JOIN trader s
ON t.tx_id = s.tx_id
INNER JOIN pools p
ON t.tx_id = p.tx_id
{% if is_incremental() %}
WHERE t._ingested_at :: DATE >= CURRENT_DATE - 2
{% endif %}

View File

@ -0,0 +1,74 @@
version: 2
models:
- name: silver__swaps
description: Records of all transactions that have occurred on Osmosis, dating back to the genesis block.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TX_ID
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: BLOCKCHAIN
description: "{{ doc('blockchain') }}"
tests:
- not_null
- name: CHAIN_ID
description: "{{ doc('chain_id') }}"
tests:
- not_null
- name: TX_ID
description: "{{ doc('tx_id') }}"
tests:
- not_null
- name: TX_STATUS
description: "{{ doc('tx_status') }}"
tests:
- not_null
- name: TRADER
description: "{{ doc('trader') }}"
tests:
- not_null
- name: SWAP_FROM_AMOUNT
description: "{{ doc('swap_from_amount') }}"
tests:
- not_null
- name: SWAP_FROM_CURRENCY
description: "{{ doc('swap_from_currency') }}"
tests:
- not_null
- name: SWAP_FROM_DECIMAL
description: "{{ doc('swap_from_decimal') }}"
- name: SWAP_TO_AMOUNT
description: "{{ doc('swap_to_amount') }}"
tests:
- not_null
- name: SWAP_TO_CURRENCY
description: "{{ doc('swap_to_currency') }}"
tests:
- not_null
- name: SWAP_TO_DECIMAL
description: "{{ doc('swap_to_decimal') }}"
- name: _INGESTED_AT
description: "{{ doc('ingested_at') }}"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- TIMESTAMP_NTZ