osmosis-models/models/silver/core/silver__balances.sql
2023-12-20 15:05:08 -05:00

103 lines
2.1 KiB
SQL

{{ config(
materialized = 'incremental',
unique_key = ['block_id', 'address', 'currency'],
incremental_strategy = 'delete+insert',
cluster_by = ['_inserted_timestamp::DATE'],
tags = ['balances']
) }}
-- depends_on: {{ ref('bronze__streamline_balances') }}
WITH base AS (
SELECT
bal.block_id,
bal.address,
b.value :denom :: STRING AS currency,
b.value :amount :: INT AS amount,
TO_TIMESTAMP_NTZ(
SUBSTR(SPLIT_PART(metadata$filename, '/', 4), 1, 10) :: NUMBER,
0
) AS _inserted_timestamp
FROM
{{ source(
'bronze_streamline',
'balances_api'
) }}
bal,
LATERAL FLATTEN (
input => balances,
outer => TRUE
) b
{% if is_incremental() %}
WHERE
0 = 1
{% endif %}
),
sl2 AS (
SELECT
A.metadata :request :headers :"x-cosmos-block-height" :: INT AS block_id,
REPLACE(
REPLACE(
A.metadata :request :url,
' {service}/{Authentication}/cosmos/bank/v1beta1/balances/'
),
'?pagination.limit=1000'
) AS address,
b.value :denom :: STRING AS currency,
b.value :amount :: INT AS amount,
_inserted_timestamp
FROM
{% if is_incremental() %}
{{ ref('bronze__streamline_balances') }}
{% else %}
{{ ref('bronze__streamline_FR_balances') }}
{% endif %}
A,
LATERAL FLATTEN (
input => DATA: balances,
outer => TRUE
) b
{% if is_incremental() %}
WHERE
_inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp)
FROM
{{ this }}
)
{% endif %}
),
combo AS (
SELECT
block_id,
address,
currency,
amount,
_inserted_timestamp
FROM
base
UNION ALL
SELECT
block_id,
address,
currency,
amount,
_inserted_timestamp
FROM
sl2
)
SELECT
block_id,
address,
currency,
amount,
_inserted_timestamp
FROM
combo qualify(ROW_NUMBER() over(PARTITION BY block_id, address, currency
ORDER BY
_inserted_timestamp DESC)) = 1