From f323d61390a11f39765af1a734742a811ff347d2 Mon Sep 17 00:00:00 2001 From: Eric Laurello Date: Fri, 16 Jun 2023 10:16:55 -0400 Subject: [PATCH] val, stake bal --- macros/idk.py | 52 ----- .../descriptions/validator_address_reward.md | 5 + .../balance/silver__balances_staked.sql | 25 +++ .../balance/silver__daily_balances_staked.sql | 177 ++++++++++++++++ .../silver/silver__validator_commission.sql | 198 ++++++++++++++++++ .../silver/silver__validator_commission.yml | 104 +++++++++ 6 files changed, 509 insertions(+), 52 deletions(-) delete mode 100644 macros/idk.py create mode 100644 models/descriptions/validator_address_reward.md create mode 100644 models/silver/balance/silver__balances_staked.sql create mode 100644 models/silver/balance/silver__daily_balances_staked.sql create mode 100644 models/silver/silver__validator_commission.sql create mode 100644 models/silver/silver__validator_commission.yml diff --git a/macros/idk.py b/macros/idk.py deleted file mode 100644 index 179c36e..0000000 --- a/macros/idk.py +++ /dev/null @@ -1,52 +0,0 @@ -# !pip install cosmospy-protobuf - -import base64 -import json -import cosmospy_protobuf.cosmos.tx.v1beta1.tx_pb2 as tx_pb2 - - - - -tx = "CrIDCq8DCigvc2VpcHJvdG9jb2wuc2VpY2hhaW4uZGV4Lk1zZ1BsYWNlT3JkZXJzEoIDCipzZWkxajh4dXhnNnd6dXBobXBscWp3aDlrZ3BhMzk0aDIzNWo4Z3Q2cDkSzgEqEzEwMDAwMDAwMDAwMDAwMDAwMDAyEzEwMDAwMDAwMDAwMDAwMDAwMDA6N2ZhY3Rvcnkvc2VpMWo4eHV4ZzZ3enVwaG1wbHFqd2g5a2dwYTM5NGgyMzVqOGd0NnA5L3N1c2RCOGZhY3Rvcnkvc2VpMWo4eHV4ZzZ3enVwaG1wbHFqd2g5a2dwYTM5NGgyMzVqOGd0NnA5L3NpbWJhWil7ImxldmVyYWdlIjoiMSIsInBvc2l0aW9uX2VmZmVjdCI6Ik9wZW4ifWoBMHIBMBo+c2VpMXV0aDk1YTRtM3JzZnRwZjQ2a3B6Y3poMnY4OHljOHk4dnFoaHN5cnhsZm1zbDJkNnZ0anNqeXUyMG0iQwo4ZmFjdG9yeS9zZWkxajh4dXhnNnd6dXBobXBscWp3aDlrZ3BhMzk0aDIzNWo4Z3Q2cDkvc2ltYmESBzEwMDAwMDASZQpNCkMKHS9jb3Ntb3MuY3J5cHRvLnNyMjU1MTkuUHViS2V5EiIKIIoXKbhOoUZVmK2FLSYXNq4TpaOMbD5seszobNsdithCEgQKAggBGCcSFAoOCgR1c2VpEgYzMDAwMDAQwJoMGkBe3rxqE6chMjZLZbHS3faXZwJcxEvg+fhxldj/4PUWPGUVffVEcGtZsEIAVa9IKJZHQ87TZBPrOKwFd3UeP6OE" -decode64 = base64.b64decode(tx) -tx = tx_pb2.Tx() -tx.ParseFromString(decode64) - - -# decode64 = decode64.decode('unicode_escape').encode('utf-8') -# decode64 = decode64.decode('utf-8') -# print(decode64) -# decode64 = decode64.decode('utf-16') -# decode64 = decode64.decode('utf-8') -# fin = str(decode64) - -# string = bytes.decode(decode64, 'utf-8') -# str = unicode(decode64, errors='ignore') -# string = decode64.decode('unicode_escape').encode('utf-8') -# print(string) - -# decode64 = decode64.rstrip("\n").decode("utf-16") -# decode64 = decode64.split("\r\n") - -string = decode64.decode('unicode_escape').encode('utf-8') -print(string) - - - -# print(tx) -# print(tx.body) -# print(tx.body.messages) -# print(tx.auth_info) -# print(tx.signatures) - - -# dictionary = {'tx':fin} -# jsonString = json.dumps(dictionary, indent=4) -# print(jsonString) - -# dictionary = {'body':tx.body, 'auth_info':tx.auth_info, 'signature':tx.signatures} -# jsonString = json.dumps(dictionary, indent=4) -# print(jsonString) - - - diff --git a/models/descriptions/validator_address_reward.md b/models/descriptions/validator_address_reward.md new file mode 100644 index 0000000..2f3f6ec --- /dev/null +++ b/models/descriptions/validator_address_reward.md @@ -0,0 +1,5 @@ +{% docs validator_address_reward %} + +The wallet address that recieves the commissiion of the validator. + +{% enddocs %} \ No newline at end of file diff --git a/models/silver/balance/silver__balances_staked.sql b/models/silver/balance/silver__balances_staked.sql new file mode 100644 index 0000000..3ff73d4 --- /dev/null +++ b/models/silver/balance/silver__balances_staked.sql @@ -0,0 +1,25 @@ +{{ config( + materialized = 'view' +) }} + +SELECT + block_id, + block_timestamp, + tx_id, + msg_group, + delegator_address AS address, + CASE + WHEN action = 'delegate' THEN amount + ELSE - amount + END AS amount, + SUM(amount) over( + PARTITION BY address, + currency + ORDER BY + block_timestamp, + msg_group rows unbounded preceding + ) AS balance, + currency, + _inserted_timestamp +FROM + {{ ref('silver__staking') }} diff --git a/models/silver/balance/silver__daily_balances_staked.sql b/models/silver/balance/silver__daily_balances_staked.sql new file mode 100644 index 0000000..4edf5db --- /dev/null +++ b/models/silver/balance/silver__daily_balances_staked.sql @@ -0,0 +1,177 @@ +{{ config( + materialized = 'incremental', + unique_key = ['date', 'address', 'currency'], + incremental_strategy = 'merge', + cluster_by = ['DATE'], + post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION ON EQUALITY(address);" +) }} + +WITH all_staked AS ( + + SELECT + block_id, + block_timestamp, + address, + balance, + currency + FROM + {{ ref('silver__balances_staked') }} +) + +{% if is_incremental() %}, +recent AS ( + SELECT + DATE, + address, + balance, + currency + FROM + {{ this }} + WHERE + DATE = ( + SELECT + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) + ), + NEW AS ( + SELECT + block_timestamp :: DATE AS DATE, + address, + balance, + currency, + 1 AS RANK + FROM + all_staked + WHERE + block_timestamp :: DATE >= ( + SELECT + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: DATE, address, currency + ORDER BY + block_timestamp DESC)) = 1 + ), + incremental AS ( + SELECT + DATE, + address, + balance, + currency + FROM + ( + SELECT + DATE, + address, + balance, + currency, + 2 AS RANK + FROM + recent + UNION + SELECT + DATE, + address, + balance, + currency, + 1 AS RANK + FROM + NEW + ) qualify(ROW_NUMBER() over (PARTITION BY DATE, address, currency + ORDER BY + RANK ASC)) = 1 + ), + {% endif %}, + base AS ( + +{% if is_incremental() %} +SELECT + DATE AS block_timestamp, address, balance, currency +FROM + incremental +{% else %} +SELECT + block_timestamp, address, balance, currency +FROM + all_staked +{% endif %}), +address_ranges AS ( + SELECT + address, + currency, + MIN( + block_timestamp :: DATE + ) AS min_block_date, + MAX ( + CURRENT_TIMESTAMP :: DATE + ) AS max_block_date + FROM + base + GROUP BY + address, + currency +), +ddate AS ( + SELECT + date_day :: DATE AS DATE + FROM + {{ source( + 'crosschain', + 'dim_dates' + ) }} + GROUP BY + DATE +), +all_dates AS ( + SELECT + d.date, + A.address, + A.currency + FROM + ddate d + LEFT JOIN address_ranges A + ON d.date BETWEEN A.min_block_date + AND A.max_block_date + WHERE + A.address IS NOT NULL +), +sei_balances AS ( + SELECT + block_timestamp, + address, + balance, + currency + FROM + base qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: DATE, address, currency + ORDER BY + block_timestamp DESC)) = 1 +), +balance_temp AS ( + SELECT + d.date, + d.address, + b.balance, + d.currency + FROM + all_dates d + LEFT JOIN sei_balances b + ON d.date = b.block_timestamp :: DATE + AND d.address = b.address + AND d.currency = b.currency +) +SELECT + DATE, + 'staked' AS balance_type, + address, + currency, + LAST_VALUE( + balance ignore nulls + ) over( + PARTITION BY address, + currency, + balance_type + ORDER BY + DATE ASC rows unbounded preceding + ) AS balance +FROM + balance_temp diff --git a/models/silver/silver__validator_commission.sql b/models/silver/silver__validator_commission.sql new file mode 100644 index 0000000..4a43043 --- /dev/null +++ b/models/silver/silver__validator_commission.sql @@ -0,0 +1,198 @@ +{{ config( + materialized = 'incremental', + unique_key = ["tx_id","msg_group","msg_sub_group"], + incremental_strategy = 'merge', + cluster_by = ['block_timestamp::DATE'] +) }} + +WITH txs AS ( + + SELECT + DISTINCT A.tx_id, + A.msg_group, + msg_sub_group + FROM + {{ ref('silver__msg_attributes') }} A + WHERE + msg_type = 'withdraw_commission' + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} +) +{% endif %} +), +msg_attributes_base AS ( + SELECT + A.tx_id, + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.msg_type, + A.msg_group, + A.msg_sub_group, + A.msg_index, + A.attribute_key, + A.attribute_value, + A._inserted_timestamp + FROM + {{ ref('silver__msg_attributes') }} A + JOIN txs b + ON A.tx_id = b.tx_id + WHERE + ( + A.msg_group = b.msg_group + AND A.msg_sub_group = b.msg_sub_group + OR ( + A.msg_group IS NULL + AND msg_type || attribute_key = 'txacc_seq' + ) + ) + AND msg_type || attribute_key IN ( + 'withdraw_commissionamount', + 'transferrecipient', + 'transferamount', + 'messagesender', + 'txacc_seq' + ) + AND NOT ( + msg_type || attribute_key = 'messagesender' + AND len(attribute_value) = 42 + ) + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} +) +{% endif %} +), +combo AS ( + SELECT + tx_id, + msg_group, + msg_sub_group, + OBJECT_AGG( + attribute_key :: STRING, + attribute_value :: variant + ) AS j, + j :sender :: STRING AS validator_address_operator, + j :amount :: STRING AS amount + FROM + msg_attributes_base + WHERE + msg_type IN ( + 'withdraw_commission', + 'message' + ) + GROUP BY + tx_id, + msg_group, + msg_sub_group +), +recipient_msg_index AS ( + SELECT + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index + FROM + msg_attributes_base A + JOIN combo b + ON A.tx_id = b.tx_id + AND A.msg_group = b.msg_group + AND A.msg_sub_group = b.msg_sub_group + WHERE + A.msg_type = 'transfer' + AND A.attribute_value = b.amount +), +recipient AS ( + SELECT + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.attribute_value AS validator_address_reward + FROM + msg_attributes_base A + JOIN recipient_msg_index b + ON A.tx_id = b.tx_id + AND A.msg_index = b.msg_index + WHERE + A.attribute_key = 'recipient' +), +tx_address AS ( + SELECT + A.tx_id, + SPLIT_PART( + attribute_value, + '/', + 0 + ) AS tx_caller_address, + SPLIT_PART( + attribute_value, + '/', + 1 + ) AS acc_seq_index + FROM + msg_attributes_base A + WHERE + attribute_key = 'acc_seq' qualify(ROW_NUMBER() over (PARTITION BY tx_id + ORDER BY + acc_seq_index) = 1) +), +block_tx_inserted AS ( + SELECT + DISTINCT A.tx_id, + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A._inserted_timestamp + FROM + msg_attributes_base A +) +SELECT + b.block_id, + b.block_timestamp, + A.tx_id, + b.tx_succeeded, + C.tx_caller_address, + A.msg_group, + A.msg_sub_group, + SPLIT_PART( + TRIM( + REGEXP_REPLACE( + am.value, + '[^[:digit:]]', + ' ' + ) + ), + ' ', + 0 + ) AS amount, + RIGHT(am.value, LENGTH(am.value) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(am.value, '[^[:digit:]]', ' ')), ' ', 0))) AS currency, + A.validator_address_operator, + d.validator_address_reward, + b._inserted_timestamp +FROM + combo A + JOIN LATERAL SPLIT_TO_TABLE( + A.amount, + ',' + ) am + JOIN block_tx_inserted b + ON A.tx_id = b.tx_id + JOIN tx_address C + ON A.tx_id = C.tx_id + JOIN recipient d + ON A.tx_id = d.tx_id + AND A.msg_group = d.msg_group + AND A.msg_sub_group = d.msg_sub_group diff --git a/models/silver/silver__validator_commission.yml b/models/silver/silver__validator_commission.yml new file mode 100644 index 0000000..65bcc09 --- /dev/null +++ b/models/silver/silver__validator_commission.yml @@ -0,0 +1,104 @@ +version: 2 +models: + - name: silver__validator_commission + description: Records of all validator commission claims + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_GROUP + - MSG_SUB_GROUP + - CURRENCY + 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: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + - name: TX_SUCCEEDED + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - BOOLEAN + - name: TX_CALLER_ADDRESS + description: "{{ doc('tx_caller_address') }}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + - dbt_expectations.expect_column_values_to_match_regex: + regex: osmo[0-9a-z]{39,39} + - name: MSG_GROUP + description: "{{ doc('msg_group') }}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: AMOUNT + description: "{{ doc('amount') }}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: CURRENCY + description: "{{ doc('currency') }}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + - name: VALIDATOR_ADDRESS_OPERATOR + description: "{{ doc('validator_address') }}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + - dbt_expectations.expect_column_values_to_match_regex: + regex: osmovaloper[0-9a-z]{39,39} + - name: VALIDATOR_ADDRESS_REWARD + description: "{{ doc('validator_address_reward') }}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - STRING + - VARCHAR + - dbt_expectations.expect_column_values_to_match_regex: + regex: osmo[0-9a-z]{39,39} + - name: _INSERTED_TIMESTAMP + description: "{{ doc('inserted_timestamp') }}" + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - TIMESTAMP_NTZ