Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
39 changes: 39 additions & 0 deletions models/terra/dbt/terra_dbt__synthetic_balances.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
{{ config(
materialized = 'incremental',
unique_key = "CONCAT_WS('-', block_timestamp, chain_id, block_id, inputs)",
incremental_strategy = 'delete+insert',
tags = ['snowflake', 'terra_silver', 'terra_balances']
) }}

WITH base_tables AS (

SELECT
*
FROM
{{ source(
'bronze',
'prod_terra_sink_645110886'
) }}
WHERE
record_content:model:class = 'terra.balances.terra_synthetic_balances_model.Terra5SyntheticBalancesModel'

{% if is_incremental() %}
AND (record_metadata :CreateTime :: INT / 1000) :: TIMESTAMP :: DATE >= ( SELECT DATEADD('day', -1, MAX(system_created_at :: DATE)) FROM {{ this }})
{% endif %}

)

SELECT
(record_metadata :CreateTime :: INT / 1000) :: TIMESTAMP AS system_created_at,
t.value :block_id :: bigint AS block_id,
t.value :block_timestamp :: TIMESTAMP AS block_timestamp,
t.value :chain_id :: STRING AS chain_id,
t.value :function_name :: STRING AS function_name,
t.value :inputs :: STRING AS inputs,
t.value :project_id :: STRING AS project_id,
t.value :project_name :: STRING AS project_name,
t.value :value_numeric :: INTEGER AS value_numeric,
t.value :value_obj :: OBJECT AS value_obj
FROM
base_tables,
LATERAL FLATTEN(input => record_content :results) t
45 changes: 42 additions & 3 deletions models/terra/gold/terra__daily_balances.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,17 +11,20 @@ WITH prices AS (

SELECT
p.symbol,
l.address_name,
DATE_TRUNC(
'day',
block_timestamp
) AS DAY,
AVG(price_usd) AS price
FROM
{{ ref('terra__oracle_prices') }}
p
{{ ref('terra__oracle_prices') }} p
LEFT JOIN {{ ref('terra__labels') }} l
on p.symbol = l.address
GROUP BY
p.symbol,
DAY
DAY,
l.address_name
)

SELECT
Expand All @@ -34,6 +37,7 @@ SELECT
balance,
balance * p.price AS balance_usd,
b.balance_type,
b.is_native,
currency
FROM
{{ ref('silver_terra__daily_balances') }} b
Expand All @@ -52,3 +56,38 @@ WHERE
{% if is_incremental() %}
AND DATE >= getdate() - INTERVAL '3 days'
{% endif %}

UNION

SELECT
date_trunc('day', b.block_timestamp) as DATE,
b.address,
address_labels.l1_label AS address_label_type,
address_labels.l2_label AS address_label_subtype,
address_labels.project_name AS address_label,
address_labels.address_name AS address_name,
balance,
balance * p.price AS balance_usd,
b.balance_type,
b.is_native,
currency
FROM {{ ref('silver_terra__block_synthetic_balances') }} b

LEFT OUTER JOIN prices p
ON p.symbol = currency
AND p.day = date_trunc('day', b.block_timestamp)

LEFT OUTER JOIN prices i
ON i.address_name = currency
AND i.day = date_trunc('day', b.block_timestamp)

LEFT OUTER JOIN {{ ref('silver_crosschain__address_labels') }} AS address_labels
ON b.address = address_labels.address
AND address_labels.blockchain = 'terra'
AND address_labels.creator = 'flipside'

WHERE balance > 0

{% if is_incremental() %}
AND date_trunc('day', block_timestamp) >= getdate() - INTERVAL '3 days'
{% endif %}
27 changes: 19 additions & 8 deletions models/terra/gold/terra__daily_balances.yml
Original file line number Diff line number Diff line change
Expand Up @@ -8,12 +8,15 @@ models:
- DATE
- CURRENCY
- BALANCE_TYPE
where: DATE > CURRENT_DATE - 30
columns:
- name: ADDRESS
tests:
- not_null
- not_null:
where: DATE > CURRENT_DATE - 30
- dbt_expectations.expect_column_values_to_match_regex:
regex: terra[0-9a-z]{39,39}
where: DATE > CURRENT_DATE - 30
# - name: ADDRESS_LABEL
# tests:
# - not_null
Expand All @@ -28,20 +31,28 @@ models:
# - not_null
- name: BALANCE
tests:
- not_null
- not_null:
where: DATE > CURRENT_DATE - 30
- name: BALANCE_TYPE
tests:
- not_null
- not_null:
where: DATE > CURRENT_DATE - 30
- name: BALANCE_USD
tests:
- not_null:
where: DATE > '2021-05-15'
#- not_null:
# where: DATE > '2021-05-15'
- name: CURRENCY
tests:
- not_null
- not_null:
where: DATE > CURRENT_DATE - 30
- name: IS_NATIVE
tests:
- not_null:
where: DATE > CURRENT_DATE - 30
- name: DATE
tests:
- not_null
- not_null:
where: DATE > CURRENT_DATE - 30
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 2
interval: 3
33 changes: 33 additions & 0 deletions models/terra/silver/silver_terra__block_synthetic_balances.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,33 @@
{{ config(
materialized = 'incremental',
unique_key = "CONCAT_WS('-', block_timestamp, address, currency)",
incremental_strategy = 'delete+insert',
cluster_by = ['block_timestamp::DATE'],
tags = ['snowflake', 'silver_terra', 'silver_terra__synthetic_balances']
) }}


with dedupe as (

SELECT
system_created_at,
block_id,
block_timestamp,
chain_id,
SUBSTRING(inputs,25,44) as address,
b.value:denom::string as currency,
'liquid' as balance_type,
false as is_native,
b.value:amount::FLOAT as balance,
row_number() OVER (PARTITION BY date_trunc('day', block_timestamp), address, currency, chain_id ORDER BY block_timestamp DESC, block_id DESC) as rn
FROM {{ ref('terra_dbt__synthetic_balances') }},
LATERAL FLATTEN(input => value_obj :balances) b
WHERE 1 = 1
)

SELECT * FROM dedupe
WHERE rn = 1

{% if is_incremental() %}
AND system_created_at :: DATE >= ( SELECT DATEADD('day', -1, MAX(system_created_at :: DATE)) FROM {{ this }})
{% endif %}
48 changes: 48 additions & 0 deletions models/terra/silver/silver_terra__block_synthetic_balances.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
version: 2
models:
- name: silver_terra__block_synthetic_balances
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- BLOCK_TIMESTAMP
- ADDRESS
- CURRENCY
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30 AND BALANCE > 0
columns:
- name: BLOCK_ID
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
- name: BLOCK_TIMESTAMP
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 3
- name: CHAIN_ID
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
- name: ADDRESS
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
- dbt_expectations.expect_column_values_to_match_regex:
regex: terra[0-9a-z]{39,39}
- name: CURRENCY
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
- name: BALANCE_TYPE
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
- name: IS_NATIVE
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
- name: BALANCE
tests:
- not_null:
where: BLOCK_TIMESTAMP > CURRENT_DATE - 30
1 change: 1 addition & 0 deletions models/terra/silver/silver_terra__daily_balances.sql
Original file line number Diff line number Diff line change
Expand Up @@ -96,6 +96,7 @@ SELECT
currency,
balance_type,
blockchain,
TRUE as is_native,
LAST_VALUE(
balance ignore nulls
) over(
Expand Down