mirror of
https://github.com/FlipsideCrypto/osmosis-models.git
synced 2026-02-06 11:26:55 +00:00
AN-1251_silver staking objects (#23)
* silver staking objects * cleanup * remove subqueries, casing , optimization * Logic simplification * updates for auto claim * Simple staking actions, using the msg index logic * update to ctime join * final formatting
This commit is contained in:
parent
04fe197b7a
commit
e586b65a81
5
models/descriptions/action.md
Normal file
5
models/descriptions/action.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs action %}
|
||||
|
||||
The action taken in the msg group. For staking this includes delegate, undelegate, redelegate, withdraw_rewards.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/amount.md
Normal file
5
models/descriptions/amount.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs amount %}
|
||||
|
||||
The amount that was used in the transaction message.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/completion_time.md
Normal file
5
models/descriptions/completion_time.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs completion_time %}
|
||||
|
||||
The time at which the undelegate or redelegate staking action is completed.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/currency.md
Normal file
5
models/descriptions/currency.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs currency %}
|
||||
|
||||
The currency that was used in the transaction message.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/delegator_address.md
Normal file
5
models/descriptions/delegator_address.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs delegator_address %}
|
||||
|
||||
The wallet address of the individual who owns the delegated asset.
|
||||
|
||||
{% enddocs %}
|
||||
@ -0,0 +1,5 @@
|
||||
{% docs redelegate_source_validator_address %}
|
||||
|
||||
The wallet address of the source alidator in a redelegation staking action.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/tx_caller_address.md
Normal file
5
models/descriptions/tx_caller_address.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs tx_caller_address %}
|
||||
|
||||
The wallet address of the individual who initiated the transaction.
|
||||
|
||||
{% enddocs %}
|
||||
5
models/descriptions/validator_address.md
Normal file
5
models/descriptions/validator_address.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs validator_address %}
|
||||
|
||||
The wallet address of the validator related to the staking action.
|
||||
|
||||
{% enddocs %}
|
||||
312
models/silver/silver__staking.sql
Normal file
312
models/silver/silver__staking.sql
Normal file
@ -0,0 +1,312 @@
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
unique_key = "CONCAT_WS('-', tx_id, msg_group, action, currency, delegator_address, validator_address)",
|
||||
incremental_strategy = 'delete+insert',
|
||||
cluster_by = ['_ingested_at::DATE'],
|
||||
) }}
|
||||
|
||||
WITH base AS (
|
||||
|
||||
SELECT
|
||||
A.tx_id,
|
||||
A.msg_type,
|
||||
A.msg_index,
|
||||
msg_group
|
||||
FROM
|
||||
{{ ref('silver__msg_attributes') }} A
|
||||
WHERE
|
||||
msg_type IN (
|
||||
'delegate',
|
||||
'redelegate',
|
||||
'unbond'
|
||||
)
|
||||
AND attribute_value NOT IN (
|
||||
'superfluid_delegate',
|
||||
'superfluid_undelegate',
|
||||
'superfluid_unbond_underlying_lock'
|
||||
)
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND _ingested_at :: DATE >= CURRENT_DATE - 2
|
||||
{% endif %}
|
||||
),
|
||||
msg_attr AS (
|
||||
SELECT
|
||||
A.tx_id,
|
||||
A.attribute_key,
|
||||
A.attribute_value,
|
||||
A.msg_index,
|
||||
A.msg_type,
|
||||
A.msg_group
|
||||
FROM
|
||||
{{ ref('silver__msg_attributes') }} A
|
||||
JOIN (
|
||||
SELECT
|
||||
DISTINCT tx_id,
|
||||
msg_index
|
||||
FROM
|
||||
base
|
||||
UNION ALL
|
||||
SELECT
|
||||
DISTINCT tx_id,
|
||||
msg_index + 1 msg_index
|
||||
FROM
|
||||
base
|
||||
) b
|
||||
ON A.tx_ID = b.tx_ID
|
||||
AND A.msg_index = b.msg_index
|
||||
WHERE
|
||||
A.msg_type IN (
|
||||
'delegate',
|
||||
'message',
|
||||
'redelegate',
|
||||
'unbond'
|
||||
)
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND _ingested_at :: DATE >= CURRENT_DATE - 2
|
||||
{% endif %}
|
||||
),
|
||||
tx_address AS (
|
||||
SELECT
|
||||
A.tx_id,
|
||||
OBJECT_AGG(
|
||||
attribute_key :: STRING,
|
||||
attribute_value :: variant
|
||||
) AS j,
|
||||
SPLIT_PART(
|
||||
j :acc_seq :: STRING,
|
||||
'/',
|
||||
0
|
||||
) AS tx_caller_address
|
||||
FROM
|
||||
osmosis_dev.silver.msg_attributes A
|
||||
JOIN (
|
||||
SELECT
|
||||
DISTINCT tx_id
|
||||
FROM
|
||||
base
|
||||
) b
|
||||
ON A.tx_ID = b.tx_ID
|
||||
WHERE
|
||||
attribute_key = 'acc_seq'
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND _ingested_at :: DATE >= CURRENT_DATE - 2
|
||||
{% endif %}
|
||||
GROUP BY
|
||||
A.tx_id,
|
||||
msg_group
|
||||
),
|
||||
valid AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index,
|
||||
OBJECT_AGG(
|
||||
attribute_key :: STRING,
|
||||
attribute_value :: variant
|
||||
) AS j,
|
||||
COALESCE(
|
||||
j :validator :: STRING,
|
||||
j :destination_validator :: STRING
|
||||
) AS validator_address,
|
||||
j :source_validator :: STRING AS redelegate_source_validator_address
|
||||
FROM
|
||||
msg_attr
|
||||
WHERE
|
||||
attribute_key LIKE '%validator'
|
||||
GROUP BY
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index
|
||||
),
|
||||
sendr AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index,
|
||||
OBJECT_AGG(
|
||||
attribute_key :: STRING,
|
||||
attribute_value :: variant
|
||||
) AS j,
|
||||
j :sender :: STRING AS sender
|
||||
FROM
|
||||
msg_attr A
|
||||
WHERE
|
||||
attribute_key = 'sender'
|
||||
GROUP BY
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index
|
||||
),
|
||||
amount AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index,
|
||||
OBJECT_AGG(
|
||||
attribute_key :: STRING,
|
||||
attribute_value :: variant
|
||||
) AS j,
|
||||
j :amount :: STRING AS amount
|
||||
FROM
|
||||
msg_attr
|
||||
WHERE
|
||||
attribute_key = 'amount'
|
||||
GROUP BY
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index
|
||||
),
|
||||
ctime AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index,
|
||||
OBJECT_AGG(
|
||||
attribute_key :: STRING,
|
||||
attribute_value :: variant
|
||||
) AS j,
|
||||
j :completion_time :: STRING AS completion_time
|
||||
FROM
|
||||
msg_attr
|
||||
WHERE
|
||||
attribute_key = 'completion_time'
|
||||
GROUP BY
|
||||
tx_id,
|
||||
msg_group,
|
||||
msg_index
|
||||
),
|
||||
prefinal AS (
|
||||
SELECT
|
||||
A.tx_ID,
|
||||
A.msg_group,
|
||||
b.sender AS delegator_address,
|
||||
d.amount,
|
||||
A.msg_type AS action,
|
||||
C.validator_address,
|
||||
C.redelegate_source_validator_address,
|
||||
e.completion_time
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DISTINCT tx_id,
|
||||
msg_group,
|
||||
msg_index,
|
||||
REPLACE(
|
||||
msg_type,
|
||||
'unbond',
|
||||
'undelegate'
|
||||
) msg_type
|
||||
FROM
|
||||
base
|
||||
) A
|
||||
JOIN sendr b
|
||||
ON A.tx_ID = b.tx_ID
|
||||
AND A.msg_group = b.msg_group
|
||||
AND A.msg_index + 1 = b.msg_index
|
||||
JOIN valid C
|
||||
ON A.tx_ID = C.tx_ID
|
||||
AND A.msg_group = C.msg_group
|
||||
AND A.msg_index = C.msg_index
|
||||
JOIN amount d
|
||||
ON A.tx_ID = d.tx_ID
|
||||
AND A.msg_group = d.msg_group
|
||||
AND A.msg_index = d.msg_index
|
||||
LEFT JOIN ctime e
|
||||
ON A.tx_ID = e.tx_ID
|
||||
AND A.msg_group = e.msg_group
|
||||
AND A.msg_index = e.msg_index
|
||||
)
|
||||
SELECT
|
||||
b.block_id,
|
||||
b.block_timestamp,
|
||||
b.blockchain,
|
||||
b.chain_id,
|
||||
A.tx_id,
|
||||
b.tx_status,
|
||||
C.tx_caller_address,
|
||||
A.action,
|
||||
A.msg_group,
|
||||
A.delegator_address,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN A.split_amount LIKE '%uosmo' THEN REPLACE(
|
||||
A.split_amount,
|
||||
'uosmo'
|
||||
)
|
||||
WHEN A.split_amount LIKE '%uion' THEN REPLACE(
|
||||
A.split_amount,
|
||||
'uion'
|
||||
)
|
||||
WHEN A.split_amount LIKE '%pool%' THEN LEFT(A.split_amount, CHARINDEX('g', A.split_amount) -1)
|
||||
WHEN A.split_amount LIKE '%ibc%' THEN LEFT(A.split_amount, CHARINDEX('i', A.split_amount) -1)
|
||||
ELSE A.split_amount
|
||||
END :: INT
|
||||
) AS amount,
|
||||
CASE
|
||||
WHEN A.split_amount LIKE '%uosmo' THEN 'uosmo'
|
||||
WHEN A.split_amount LIKE '%uion' THEN 'uion'
|
||||
WHEN A.split_amount LIKE '%pool%' THEN SUBSTRING(A.split_amount, CHARINDEX('g', A.split_amount), 99)
|
||||
WHEN A.split_amount LIKE '%ibc%' THEN SUBSTRING(A.split_amount, CHARINDEX('i', A.split_amount), 99)
|
||||
ELSE 'uosmo'
|
||||
END AS currency,
|
||||
A.validator_address,
|
||||
A.redelegate_source_validator_address,
|
||||
A.completion_time :: datetime completion_time,
|
||||
b._INGESTED_AT
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
p.tx_Id,
|
||||
p.action,
|
||||
p.msg_group,
|
||||
p.delegator_address,
|
||||
p.validator_address,
|
||||
p.redelegate_source_validator_address,
|
||||
p.completion_time,
|
||||
am.value AS split_amount
|
||||
FROM
|
||||
prefinal p,
|
||||
LATERAL SPLIT_TO_TABLE(
|
||||
p.amount,
|
||||
','
|
||||
) am
|
||||
) A
|
||||
JOIN (
|
||||
SELECT
|
||||
tx_ID,
|
||||
block_id,
|
||||
block_timestamp,
|
||||
blockchain,
|
||||
chain_id,
|
||||
tx_status,
|
||||
_INGESTED_AT
|
||||
FROM
|
||||
{{ ref('silver__transactions') }}
|
||||
|
||||
{% if is_incremental() %}
|
||||
WHERE
|
||||
_ingested_at :: DATE >= CURRENT_DATE - 2
|
||||
{% endif %}
|
||||
) b
|
||||
ON A.tx_Id = b.tx_ID
|
||||
JOIN tx_address C
|
||||
ON A.tx_id = C.tx_id
|
||||
GROUP BY
|
||||
b.block_id,
|
||||
b.block_timestamp,
|
||||
b.blockchain,
|
||||
b.chain_id,
|
||||
A.tx_id,
|
||||
b.tx_status,
|
||||
C.tx_caller_address,
|
||||
A.action,
|
||||
A.msg_group,
|
||||
A.delegator_address,
|
||||
currency,
|
||||
A.validator_address,
|
||||
A.redelegate_source_validator_address,
|
||||
completion_time,
|
||||
b._INGESTED_AT
|
||||
98
models/silver/silver__staking.yml
Normal file
98
models/silver/silver__staking.yml
Normal file
@ -0,0 +1,98 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__staking
|
||||
description: Records of all staking related transactions that have occurred on Osmosis, dating back to the genesis block. These actions include delegate, undelegate, and redelegate.
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- TX_ID
|
||||
- MSG_GROUP
|
||||
- ACTION
|
||||
- CURRENCY
|
||||
- DELEGATOR_ADDRESS
|
||||
- VALIDATOR_ADDRESS
|
||||
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: TX_CALLER_ADDRESS
|
||||
description: "{{ doc('tx_caller_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: ACTION
|
||||
description: "{{ doc('action') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
- name: MSG_GROUP
|
||||
description: "{{ doc('msg_group') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: DELEGATOR_ADDRESS
|
||||
description: "{{ doc('delegator_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: AMOUNT
|
||||
description: "{{ doc('amount') }}"
|
||||
- name: CURRENCY
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
description: "{{ doc('currency') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: VALIDATOR_ADDRESS
|
||||
description: "{{ doc('validator_address') }}"
|
||||
tests:
|
||||
- not_null
|
||||
- name: REDELEGATE_SOURCE_VALIDATOR_ADDRESS
|
||||
description: "{{ doc('redelegate_source_validator_address') }}"
|
||||
- name: COMPLETION_TIME
|
||||
description: "{{ doc('completion_time') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- TIMESTAMP_NTZ
|
||||
- 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
|
||||
Loading…
Reference in New Issue
Block a user