osmosis-models/models/silver/silver__staked_balances.sql
eric-laurello e3482847d3
AN-2245 superfluid staked balances (#64)
* check in

* WIP check in

* WIP check in

* locked LP actions and balances

* add business logic test, fix test failure & typos

* ds store

* ds store

* more logic tests
2022-10-21 13:18:58 -04:00

78 lines
1.7 KiB
SQL

{{ config(
materialized = 'incremental',
incremental_strategy = 'delete+insert',
cluster_by = ['block_timestamp'],
) }}
WITH all_staked AS (
SELECT
block_id,
block_timestamp,
delegator_address AS address,
amount,
currency,
CASE
WHEN currency LIKE 'gamm/pool/%' THEN 18
ELSE raw_metadata [1] :exponent
END AS DECIMAL,
_inserted_timestamp
FROM
{{ ref('silver__staking') }}
s
LEFT OUTER JOIN {{ ref('silver__asset_metadata') }} A
ON s.currency = A.address
WHERE
action = 'delegate'
{% if is_incremental() %}
AND block_timestamp :: DATE >=(
SELECT
DATEADD('day', -2, MAX(block_timestamp))
FROM
{{ this }})
{% endif %}
UNION ALL
SELECT
block_id,
block_timestamp,
delegator_address AS address,- amount,
currency,
CASE
WHEN currency LIKE 'gamm/pool/%' THEN 18
ELSE raw_metadata [1] :exponent
END AS DECIMAL,
_inserted_timestamp
FROM
{{ ref('silver__staking') }}
s
LEFT OUTER JOIN {{ ref('silver__asset_metadata') }} A
ON s.currency = A.address
WHERE
action = 'undelegate'
{% if is_incremental() %}
AND block_timestamp :: DATE >=(
SELECT
DATEADD('day', -2, MAX(block_timestamp))
FROM
{{ this }})
{% endif %}
)
SELECT
block_id,
block_timestamp,
'staked' AS balance_type,
address,
currency,
DECIMAL,
SUM(amount) over(
PARTITION BY address,
currency
ORDER BY
block_timestamp ASC rows unbounded preceding
) AS balance,
_inserted_timestamp
FROM
all_staked