From e3482847d3d367c2e51097febba2b76e91e6d759 Mon Sep 17 00:00:00 2001 From: eric-laurello <102970824+eric-laurello@users.noreply.github.com> Date: Fri, 21 Oct 2022 13:18:58 -0400 Subject: [PATCH] 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 --- .DS_Store | Bin 6148 -> 10244 bytes .gitignore | 14 +- data/testing__daily_balances.csv | 98 ++++ data/testing__locked_liquidity_balances.csv | 21 + data/testing__superfluid_staked_balances.csv | 22 + macros/tests/compare_model_subset.sql | 29 + .../core__fact_locked_liquidity_actions.sql | 27 + .../core__fact_locked_liquidity_actions.yml | 81 +++ models/core/core__fact_superfluid_staking.sql | 35 +- models/core/core__fact_superfluid_staking.yml | 10 +- models/descriptions/is_superfluid.md | 5 + models/descriptions/lock_duration.md | 5 + models/descriptions/lock_id.md | 5 + models/descriptions/locker_address.md | 5 + models/descriptions/msg_action.md | 5 + models/descriptions/msg_action_description.md | 5 + models/descriptions/unlock_time.md | 5 + models/descriptions/unpool_new_lock_ids.md | 5 + models/silver/silver__daily_balances.sql | 509 ++++++++++-------- models/silver/silver__daily_balances.yml | 11 + .../silver__locked_liquidity_actions.sql | 342 ++++++++++++ .../silver__locked_liquidity_actions.yml | 88 +++ .../silver__locked_liquidity_balances.sql | 179 ++++++ .../silver__locked_liquidity_balances.yml | 56 ++ .../silver__locked_liquidity_transactions.sql | 43 ++ .../silver__locked_liquidity_transactions.yml | 28 + models/silver/silver__staked_balances.sql | 130 +++-- models/silver/silver__superfluid_actions.sql | 83 +++ models/silver/silver__superfluid_actions.yml | 80 +++ .../silver__superfluid_staked_balances.sql | 71 +++ .../silver__superfluid_staked_balances.yml | 46 ++ models/silver/silver__superfluid_staking.sql | 246 ++++----- models/silver/silver__superfluid_staking.yml | 12 +- models/silver/silver__tx_body_msgs.sql | 56 ++ models/silver/silver__tx_body_msgs.yml | 57 ++ 35 files changed, 1919 insertions(+), 495 deletions(-) create mode 100644 data/testing__daily_balances.csv create mode 100644 data/testing__locked_liquidity_balances.csv create mode 100644 data/testing__superfluid_staked_balances.csv create mode 100644 macros/tests/compare_model_subset.sql create mode 100644 models/core/core__fact_locked_liquidity_actions.sql create mode 100644 models/core/core__fact_locked_liquidity_actions.yml create mode 100644 models/descriptions/is_superfluid.md create mode 100644 models/descriptions/lock_duration.md create mode 100644 models/descriptions/lock_id.md create mode 100644 models/descriptions/locker_address.md create mode 100644 models/descriptions/msg_action.md create mode 100644 models/descriptions/msg_action_description.md create mode 100644 models/descriptions/unlock_time.md create mode 100644 models/descriptions/unpool_new_lock_ids.md create mode 100644 models/silver/silver__locked_liquidity_actions.sql create mode 100644 models/silver/silver__locked_liquidity_actions.yml create mode 100644 models/silver/silver__locked_liquidity_balances.sql create mode 100644 models/silver/silver__locked_liquidity_balances.yml create mode 100644 models/silver/silver__locked_liquidity_transactions.sql create mode 100644 models/silver/silver__locked_liquidity_transactions.yml create mode 100644 models/silver/silver__superfluid_actions.sql create mode 100644 models/silver/silver__superfluid_actions.yml create mode 100644 models/silver/silver__superfluid_staked_balances.sql create mode 100644 models/silver/silver__superfluid_staked_balances.yml create mode 100644 models/silver/silver__tx_body_msgs.sql create mode 100644 models/silver/silver__tx_body_msgs.yml diff --git a/.DS_Store b/.DS_Store index 70bb8ca9bc403ffd87e3945ea77fae77219fdfe7..d0002317adba036f5a0463ae97b6914f83d17e8f 100644 GIT binary patch literal 10244 zcmeHM&1(}u6rZtayRnt#P(ktFiXaN5rm>$05@Wn*55-75G!m00B(ceENYaK9ifP4z z9|!T^(TkvXD&oP9lLztaMe!o`=3gLsQs0}IY-W<(prA#{49vXEyx*Jm<~MJ5mJH6-WK#>4R=o;5mQ~AWb2|LN>Sr4HU{v zL2^?nju@1iL%%6-VIdn_a&tn(;e!g#RGd&K^A6*i3{Gg6OWkS)Gy|Os;Mv_rMoE_B zNmV(&53O&>x}qJ8rV4fn`i#e!n-4eYZ%(WFbXR>TC*2KPeGR7Y#wUpdwLn%$g=9!Y z@s9`>j2y>G{L^UB&*JD9t7y04>4sC{;y!&O4N+A|(j^{8C&zIh?ZhGJTmIejE`A5W zZwmY-ND2Hek|k)f$V;kLDGBahq)LT+r5X%=pu2i}y?y;gzcFB3j^*rHteUJYS0c&s z0{*&a+l5r~IhmTzXKIPS@EO~xCi7ON%nb7B3_#+S@>bfeMeJoOU17E{t}y(DKM~kh zuTRW`M$C!e^xBA7p9uv=%<&VGYioXE@8RPoFC>-B1{h=cVZ}2?y99zzV-@z;Evay8|@Em(3R<;VZl?4pW8`s{3b#u#OM<>Vs z*;4X`*~;;{>6Q2}I`mrrzgg8U{rKd&tdsq2#y1~Dj*0hI*vfw0^s-<2&duRiN|(#P+U-QyhE>?x84=m+Bdo*mDsuGKHRlP zne7_tZazOX3J^sv$Fy*5c=mjgLum||LobXHNBk~E(hG6GzU9G>q?Kcseg3t%jtZj1 zhdV;?&w0?TW# Z{{PdZv&gf_8$~}())MERm@;iKI|qj# lGek;&8%Vo?oWC*gJM(0I6;F_77?>a)1NoI= ( - SELECT - DATEADD('day', -1, MAX(DATE)) - FROM - {{ this }} - ) - - qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: date, address, balance_type, currency - ORDER BY - block_timestamp DESC)) = 1 - - UNION ALL - - SELECT - block_timestamp :: date AS date, - balance_type, - address, - balance, - currency, - decimal, - 1 AS RANK - FROM - {{ ref('silver__staked_balances') }} - - WHERE block_timestamp :: date >= ( - SELECT - DATEADD('day', -1, MAX(DATE)) - FROM - {{ this }} - ) - - qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: date, address, balance_type, currency - ORDER BY - block_timestamp DESC)) = 1 - -), - -incremental AS ( SELECT - date, - balance_type, - address, - balance, - currency, - decimal - FROM - ( + DATE, + balance_type, + address, + balance, + currency, + DECIMAL + FROM + {{ this }} + WHERE + DATE = ( SELECT - date, - balance_type, - address, - balance, - currency, - decimal, - 2 AS RANK - FROM - recent - - UNION - + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) + ), + NEW AS ( SELECT - date, - balance_type, - address, - balance, - currency, - decimal, + block_timestamp :: DATE AS DATE, + balance_type, + address, + balance, + currency, + DECIMAL, 1 AS RANK - FROM - new - ) + FROM + {{ ref('silver__liquid_balances') }} + WHERE + block_timestamp :: DATE >= ( + SELECT + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: DATE, address, balance_type, currency + ORDER BY + block_timestamp DESC)) = 1 + UNION ALL + SELECT + block_timestamp :: DATE AS DATE, + balance_type, + address, + balance, + currency, + DECIMAL, + 1 AS RANK + FROM + {{ ref('silver__staked_balances') }} + WHERE + block_timestamp :: DATE >= ( + SELECT + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: DATE, address, balance_type, currency + ORDER BY + block_timestamp DESC)) = 1 + UNION ALL + SELECT + block_timestamp, + balance_type, + address, + SUM(balance) AS balance, + currency, + DECIMAL, + 1 AS RANK + FROM + ( + SELECT + block_timestamp, + balance_type, + address, + balance, + currency, + DECIMAL, + 1 AS RANK + FROM + {{ ref('silver__locked_liquidity_balances') }} + WHERE + block_timestamp :: DATE >= ( + SELECT + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) + AND lock_id || '---' || block_timestamp :: DATE :: STRING NOT IN ( + SELECT + lock_id || '---' || block_timestamp :: DATE :: STRING + FROM + {{ ref('silver__superfluid_staked_balances') }} + WHERE + block_timestamp :: DATE >= ( + SELECT + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) + ) qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: DATE, address, balance_type, currency, lock_id + ORDER BY + block_timestamp DESC)) = 1 + UNION ALL + SELECT + block_timestamp, + balance_type, + address, + balance, + currency, + DECIMAL, + 1 AS RANK + FROM + {{ ref('silver__superfluid_staked_balances') }} + WHERE + block_timestamp :: DATE >= ( + SELECT + DATEADD('day', -1, MAX(DATE)) + FROM + {{ this }}) qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: DATE, address, balance_type, currency, lock_id + ORDER BY + block_timestamp DESC)) = 1 + ) liq + GROUP BY + block_timestamp, + balance_type, + address, + currency, + DECIMAL + ), + incremental AS ( + SELECT + DATE, + balance_type, + address, + balance, + currency, + DECIMAL + FROM + ( + SELECT + DATE, + balance_type, + address, + balance, + currency, + DECIMAL, + 2 AS RANK + FROM + recent + UNION + SELECT + DATE, + balance_type, + address, + balance, + currency, + DECIMAL, + 1 AS RANK + FROM + NEW + ) qualify(ROW_NUMBER() over (PARTITION BY DATE, address, balance_type, currency + ORDER BY + RANK ASC)) = 1 + ), + {% endif %} - qualify(ROW_NUMBER() over (PARTITION BY date, address, balance_type, currency - ORDER BY - RANK ASC)) = 1 - -), -{% endif %} - - -base AS ( - - {% if is_incremental() %} - - SELECT - date AS block_timestamp, - balance_type, - address, - balance, - currency, - decimal - FROM - incremental - - {% else %} - - SELECT - block_timestamp, - balance_type, - address, - balance, - currency, - decimal - FROM - {{ ref('silver__liquid_balances') }} - - UNION ALL - - SELECT - block_timestamp, - balance_type, - address, - balance, - currency, - decimal - FROM - {{ ref('silver__staked_balances') }} - - {% endif %} -), + base AS ( +{% if is_incremental() %} +SELECT + DATE AS block_timestamp, balance_type, address, balance, currency, DECIMAL +FROM + incremental +{% else %} +SELECT + block_timestamp, balance_type, address, balance, currency, DECIMAL +FROM + {{ ref('silver__liquid_balances') }} +UNION ALL +SELECT + block_timestamp, balance_type, address, balance, currency, DECIMAL +FROM + {{ ref('silver__staked_balances') }} +UNION ALL +SELECT + block_timestamp, balance_type, address, SUM(balance) AS balance, currency, DECIMAL +FROM + ( +SELECT + block_timestamp, balance_type, address, balance, currency, DECIMAL +FROM + {{ ref('silver__locked_liquidity_balances') }} +WHERE + lock_id || '---' || block_timestamp :: DATE :: STRING NOT IN ( +SELECT + lock_id || '---' || block_timestamp :: DATE :: STRING +FROM + {{ ref('silver__superfluid_staked_balances') }}) +UNION ALL +SELECT + block_timestamp, balance_type, address, balance, currency, DECIMAL +FROM + {{ ref('silver__superfluid_staked_balances') }}) liq +GROUP BY + block_timestamp, balance_type, address, currency, DECIMAL +{% endif %}), address_ranges AS ( SELECT - address, - balance_type, - currency, - decimal, + address, + balance_type, + currency, + DECIMAL, MIN( - block_timestamp :: date - ) AS min_block_date, + block_timestamp :: DATE + ) AS min_block_date, MAX ( - CURRENT_TIMESTAMP :: date + CURRENT_TIMESTAMP :: DATE ) AS max_block_date - FROM - base - GROUP BY - address, - balance_type, - currency, - decimal -), - -ddate AS ( - SELECT - hour :: date AS date - FROM - {{ source( - 'shared2', - 'hours' - ) }} - GROUP BY date -), - -all_dates AS ( - SELECT - d.date, - a.balance_type, - a.address, - a.currency, - a.decimal - 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 -), - -osmosis_balances AS ( - SELECT - block_timestamp, - balance_type, - address, - balance, - currency, - decimal FROM base - - qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: date, address, balance_type, currency - ORDER BY - block_timestamp DESC)) = 1 -), - + GROUP BY + address, + balance_type, + currency, + DECIMAL +), +ddate AS ( + SELECT + HOUR :: DATE AS DATE + FROM + {{ source( + 'shared2', + 'hours' + ) }} + GROUP BY + DATE +), +all_dates AS ( + SELECT + d.date, + A.balance_type, + A.address, + A.currency, + A.decimal + 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 +), +osmosis_balances AS ( + SELECT + block_timestamp, + balance_type, + address, + balance, + currency, + DECIMAL + FROM + base qualify(ROW_NUMBER() over (PARTITION BY block_timestamp :: DATE, address, balance_type, currency + ORDER BY + block_timestamp DESC)) = 1 +), balance_temp AS ( SELECT - d.date, - d.balance_type, - d.address, - b.balance, + d.date, + d.balance_type, + d.address, + b.balance, d.currency, d.decimal - - FROM - all_dates d - - LEFT JOIN osmosis_balances b - ON d.date = b.block_timestamp :: date - AND d.address = b.address - AND d.currency = b.currency - AND d.balance_type = b.balance_type + FROM + all_dates d + LEFT JOIN osmosis_balances b + ON d.date = b.block_timestamp :: DATE + AND d.address = b.address + AND d.currency = b.currency + AND d.balance_type = b.balance_type ) - SELECT - date, - balance_type, - address, - currency, - decimal, + DATE, + balance_type, + address, + currency, + DECIMAL, LAST_VALUE( balance ignore nulls ) over( - PARTITION BY address, - currency, - balance_type - ORDER BY - DATE ASC rows unbounded preceding - ) AS balance -FROM - balance_temp \ No newline at end of file + PARTITION BY address, + currency, + balance_type + ORDER BY + DATE ASC rows unbounded preceding + ) AS balance +FROM + balance_temp diff --git a/models/silver/silver__daily_balances.yml b/models/silver/silver__daily_balances.yml index 2f24bee..569f02e 100644 --- a/models/silver/silver__daily_balances.yml +++ b/models/silver/silver__daily_balances.yml @@ -9,6 +9,17 @@ models: - ADDRESS - BALANCE_TYPE - CURRENCY + - compare_model_subset: + name: silver__daily_balances_business_logic_test + compare_model: ref('testing__daily_balances') + compare_columns: + - date + - balance_type + - address + - currency + - balance + model_condition: "where date = '2022-10-17' + and ADDRESS IN ('osmo195khh6nr3zsvaxkm53wavkxv46uucdlatdux5m','osmo1ka4zctlzr2uee5s29y9qn2rcer3hcaunxvcptc','osmo1fjh798fyn9vqldc8ru09c99r89v5mt3czu4jfp')" columns: - name: DATE description: The day the balance was recorded on. diff --git a/models/silver/silver__locked_liquidity_actions.sql b/models/silver/silver__locked_liquidity_actions.sql new file mode 100644 index 0000000..c2fecd3 --- /dev/null +++ b/models/silver/silver__locked_liquidity_actions.sql @@ -0,0 +1,342 @@ +{{ config( + materialized = 'incremental', + unique_key = "_unique_key", + incremental_strategy = 'merge', + cluster_by = ['block_timestamp::DATE','_inserted_timestamp::DATE'] +) }} + +WITH + +{% if is_incremental() %} +max_date AS ( + + SELECT + MAX( + _inserted_timestamp + ) _inserted_timestamp + FROM + {{ this }} +), +{% endif %} + +base_msg_atts AS ( + SELECT + A.block_id, + A.block_timestamp, + A.blockchain, + A.chain_id, + A.tx_id, + 'SUCCEEDED' AS tx_status, + A.msg_group, + A.msg_type, + A.attribute_key, + A.attribute_value, + COALESCE( + b.lock_id :: INT, + C.lock_id :: INT + ) AS lock_id, + A._inserted_timestamp + FROM + {{ ref('silver__msg_attributes') }} A + LEFT JOIN {{ ref('silver__locked_liquidity_transactions') }} + b + ON A.tx_id = b.tx_id + AND A.msg_group = b.msg_group + LEFT JOIN {{ ref('silver__superfluid_actions') }} C + ON A.tx_id = C.tx_id + AND A.msg_group = C.msg_group + WHERE + COALESCE( + b.tx_id, + C.tx_id + ) IS NOT NULL + AND ( + ( + A.msg_type = 'message' + AND A.attribute_key = 'action' + ) + OR A.msg_type IN ( + 'add_tokens_to_lock', + 'begin_unlock', + 'begin_unlock_all', + {# 'burn', #} --these are just the placeholder osmo we can ignore + 'lock_tokens', + 'superfluid_delegate', + 'superfluid_increase_delegation', + 'superfluid_unbond_lock', + 'superfluid_undelegate', + 'unbond', + 'unlock', + 'unlock_tokens', + 'unpool_pool_id' + ) + AND attribute_key IN ( + 'amount', + 'owner', + 'burner', + 'duration', + 'unlock_time', + 'sender', + 'denom', + 'new_lock_ids' + ) + ) --weird transactions that break the logic + AND A.tx_id NOT IN ( + '523CBB1403A90A2A45A90ADFFC17F72100B99C286BD66DEDF22DD7F8A825127D', + 'B26B72516A670B4FFD31F4F7853E65F7463F7A46BDE61800DC17A41F55AB87A3', + '34A6CEF2A87D6DB15DA1D7238D3A3BEABF8B4A1B460082B3C1F6C65DE5329CAC', + '504A0BD295DA63E28D55BC7C46575C6C49D9C2612D0AF118BA2A33A089A25A6D', + 'B312127A7914D26444DA2C1104122F9CB7D3B50940F079544775C7EA4EE4981D', + '413991DF25FF3A217BA42D84D811CABC4A580F12FA9A8BC204E45F22529185CB' + ) + +{% if is_incremental() %} +AND A._inserted_timestamp >= ( + SELECT + _inserted_timestamp + FROM + max_date +) +{% endif %} +), +tx_msg_flat AS ( + SELECT + block_id, + block_timestamp, + blockchain, + chain_id, + tx_id, + tx_status, + msg_group, + _inserted_timestamp, + LISTAGG( + DISTINCT msg_type, + '-' + ) within GROUP ( + ORDER BY + msg_type + ) AS msg_type, + lock_id, + OBJECT_AGG( + msg_type :: STRING || '--' || attribute_key :: STRING, + attribute_value :: variant + ) AS j + FROM + base_msg_atts + WHERE + msg_type <> 'message' + GROUP BY + block_id, + block_timestamp, + blockchain, + chain_id, + tx_id, + tx_status, + msg_group, + lock_id, + _inserted_timestamp +), +msg_based AS ( + SELECT + A.block_id, + A.block_timestamp, + A.blockchain, + A.chain_id, + A.tx_id, + A.tx_status, + A.msg_group, + A.msg_type, + A.lock_id, + b.attribute_value AS action, + CASE + WHEN b.attribute_value = '/osmosis.lockup.MsgExtendLockup' THEN 'extend lockup' + WHEN A.msg_type = 'unpool_pool_id' THEN 'unpool' + WHEN j :"lock_tokens--duration" IS NOT NULL THEN 'initial lock' + WHEN j :: STRING ILIKE '%unlock%' + OR j :: STRING ILIKE '%undelegate%' + OR j :: STRING ILIKE '%unbond%' + OR action ILIKE '%undelegate%' THEN 'unlock-undelegate' + WHEN j :: STRING LIKE '%add%' + OR j :: STRING LIKE '%increase%' THEN 'add to position' + WHEN j :: STRING ILIKE '%delegate%' THEN 'super upgrade' + END hybrid_action, + COALESCE( + j :"add_tokens_to_lock--amount", + j :"lock_tokens--amount", + j :"superfluid_increase_delegation--amount", + j :"burn--amount", + j :"unpool_pool_id--denom" + ) :: STRING AS amount, + COALESCE( + j :"add_tokens_to_lock--owner", + j :"lock_tokens--owner", + j :"begin_unlock--owner", + j :"unlock--owner", + j :"burn--burner", + j :"unpool_pool_id--sender" + ) :: STRING AS locker, + COALESCE( + j :"lock_tokens--duration", + j :"begin_unlock--duration", + j :"unlock--duration" + ) :: STRING AS DURATION, + NULLIF( + COALESCE( + j :"lock_tokens--unlock_time", + j :"begin_unlock--unlock_time", + j :"unlock--unlock_time" + ) :: STRING, + '0001-01-01 00:00:00 +0000 UTC' + ) AS unlock_time, + j :"unpool_pool_id--new_lock_ids" :: STRING AS new_lock_ids, + A._INSERTED_TIMESTAMP + FROM + tx_msg_flat A + LEFT JOIN base_msg_atts b + ON A.tx_id = b.tx_id + AND A.msg_group = b.msg_group + AND A.lock_id = b.lock_id + AND b.msg_type = 'message' +), +combo_with_super_undel AS ( + SELECT + * + FROM + msg_based + UNION ALL + SELECT + A.block_id, + A.block_timestamp, + A.blockchain, + A.chain_id, + A.tx_id, + A.tx_status, + A.msg_group, + A.msg_type, + A.lock_id, + 'unlock' AS action, + 'unlock' AS hybrid_action, + NULL :: STRING AS amount, + delegator_address AS locker, + NULL :: STRING AS DURATION, + NULL :: STRING AS unlock_time, + NULL :: STRING AS new_lock_ids, + A._INSERTED_TIMESTAMP + FROM + {{ ref('silver__superfluid_actions') }} A + WHERE + msg_type = '/osmosis.superfluid.MsgSuperfluidUndelegate' +), +tx_body AS ( + SELECT + tx_id, + tx_status, + msg_type, + msg_group, + delegator_address, + amount, + validator_address, + lock_id, + pool_id + FROM + {{ ref('silver__superfluid_actions') }} A + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + _inserted_timestamp + FROM + max_date + ) +{% endif %} +), +all_super_pools AS ( + SELECT + lock_id, + MIN(block_id) block_id + FROM + {{ ref('silver__superfluid_actions') }} + GROUP BY + lock_id +) +SELECT + A.block_id, + A.block_timestamp, + A.blockchain, + A.chain_id, + A.tx_id, + A.tx_status, + A.msg_group, + A.msg_type, + COALESCE( + b.msg_type, + A.action + ) AS msg_action, + A.hybrid_action AS msg_action_description, + A.locker AS locker_address, + A.lock_id, + CASE + WHEN A.amount LIKE 'gamm%' THEN NULL + WHEN A.amount LIKE '%uosmo' THEN REPLACE( + A.amount, + 'uosmo' + ) + ELSE SPLIT_PART( + TRIM( + REGEXP_REPLACE( + A.amount, + '[^[:digit:]]', + ' ' + ) + ), + ' ', + 0 + ) + END :: INT {# / pow( + 10, + 18 +) #} +AS amount, +CASE + WHEN A.amount LIKE 'gamm%' THEN A.amount + WHEN A.amount LIKE '%uosmo' THEN 'uosmo' + ELSE RIGHT(A.amount, LENGTH(A.amount) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(A.amount, '[^[:digit:]]', ' ')), ' ', 0))) +END AS currency, +CASE + WHEN A.amount LIKE '%uosmo' THEN 6 + ELSE 18 +END AS DECIMAL, +COALESCE( + b.pool_id, + CASE + WHEN A.amount LIKE '%pool%' THEN RIGHT(A.amount, len(A.amount) - POSITION('pool', A.amount) -4) + END :: INT +) AS pool_id, +A.duration AS lock_duration, +A.unlock_time AS unlock_time, +CASE + WHEN b.tx_id IS NOT NULL + OR C.lock_id IS NOT NULL + AND A.block_id >= C.block_id THEN TRUE + ELSE FALSE +END is_superfluid, +A.new_lock_ids AS unpool_new_lock_ids, +concat_ws( + '-', + A.tx_id, + A.msg_group, + COALESCE( + A.lock_id, + -1 + ), + A.locker +) AS _unique_key, +A._INSERTED_TIMESTAMP +FROM + combo_with_super_undel A + LEFT JOIN tx_body b + ON A.tx_id = b.tx_id + AND A.msg_group = b.msg_group + LEFT JOIN all_super_pools C + ON A.lock_id = C.lock_id diff --git a/models/silver/silver__locked_liquidity_actions.yml b/models/silver/silver__locked_liquidity_actions.yml new file mode 100644 index 0000000..addd8bf --- /dev/null +++ b/models/silver/silver__locked_liquidity_actions.yml @@ -0,0 +1,88 @@ +version: 2 +models: + - name: silver__locked_liquidity_actions + description: Records of all LP token locking transactions that have occurred on Osmosis, dating back to the genesis block. These actions include lock, unlock, unpool, and all superfluid actions. + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_GROUP + - LOCK_ID + - LOCKER_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: 2 + - 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: MSG_GROUP + description: "{{ doc('msg_group') }}" + tests: + - not_null + - name: MSG_TYPE + description: "{{ doc('msg_type') }}" + tests: + - not_null + - name: MSG_ACTION + description: "{{ doc('action') }}" + tests: + - not_null + - name: MSG_ACTION_DESCRIPTION + description: "{{ doc('msg_action_description') }}" + tests: + - not_null + - name: LOCKER_ADDRESS + description: "{{ doc('locker_address') }}" + tests: + - not_null + - name: LOCK_ID + description: "{{ doc('lock_id') }}" + - name: AMOUNT + description: "{{ doc('amount') }}" + - name: CURRENCY + description: "{{ doc('currency') }}" + - name: POOL_ID + description: "{{ doc('pool_id') }}" + - name: LOCK_DURATION + description: "{{ doc('lock_duration') }}" + - name: UNLOCK_TIME + description: "{{ doc('unlock_time') }}" + - name: IS_SUPERFLUID + description: "{{ doc('is_superfluid') }}" + tests: + - not_null + - name: UNPOOL_NEW_LOCK_IDS + description: "{{ doc('unpool_new_lock_ids') }}" + - name: _INSERTED_TIMESTAMP + description: "{{ doc('inserted_timestamp') }}" + tests: + - not_null diff --git a/models/silver/silver__locked_liquidity_balances.sql b/models/silver/silver__locked_liquidity_balances.sql new file mode 100644 index 0000000..f50092a --- /dev/null +++ b/models/silver/silver__locked_liquidity_balances.sql @@ -0,0 +1,179 @@ +{{ config( + materialized = 'incremental', + unique_key = "_unique_key", + incremental_strategy = 'merge', + cluster_by = ['block_timestamp::DATE'], +) }} + +WITH all_staked AS ( + + SELECT + block_id, + block_timestamp, + locker_address AS address, + SUM(amount) amount, + currency, + DECIMAL, + lock_id, + _inserted_timestamp + FROM + {{ ref('silver__locked_liquidity_actions') }} + s + WHERE + msg_action_description IN ( + 'initial lock', + 'add to position' + ) + AND amount > 0 + +{% if is_incremental() %} +AND block_timestamp :: DATE >=( + SELECT + DATEADD('day', -2, MAX(block_timestamp)) + FROM + {{ this }}) + {% endif %} + GROUP BY + block_id, + block_timestamp, + locker_address, + currency, + DECIMAL, + lock_id, + _inserted_timestamp +), +undel_base AS ( + SELECT + DISTINCT block_id, + block_timestamp, + locker_address AS address, + currency, + DECIMAL, + lock_id, + msg_action_description, + tx_id, + _inserted_timestamp + FROM + {{ ref('silver__locked_liquidity_actions') }} + WHERE + msg_action_description IN ( + 'unlock', + 'unlock-undelegate', + 'unpool' + ) + +{% if is_incremental() %} +AND block_timestamp :: DATE >=( + SELECT + DATEADD('day', -2, MAX(block_timestamp)) + FROM + {{ this }}) + {% endif %} +), +unpool_lock_val AS ( + SELECT + A.lock_id, + A.currency, + A.locker_address, + b.block_id, + b.tx_id + FROM + {{ ref('silver__locked_liquidity_actions') }} A + JOIN undel_base b + ON b.msg_action_description = 'unpool' + AND A.locker_address = b.address + AND A.currency = b.currency + AND A.block_id < b.block_id + WHERE + A.lock_id IS NOT NULL qualify(ROW_NUMBER() over(PARTITION BY A.lock_id + ORDER BY + A.block_id DESC) = 1) +), +undel_bal AS ( + SELECT + A.lock_id, + A.currency, + A.decimal, + SUM(COALESCE(amount, 0)) amount + FROM + {{ ref('silver__locked_liquidity_actions') }} A + LEFT JOIN unpool_lock_val C + ON A.locker_address = C.locker_address + AND A.currency = C.currency + AND A.block_id <= C.block_id + LEFT JOIN undel_base b + ON A.lock_id = b.lock_id + LEFT JOIN undel_base bb + ON C.tx_id = bb.tx_id + WHERE + ( + bb.address IS NOT NULL + OR b.address IS NOT NULL + ) + AND A.amount > 0 + AND A.msg_action_description IN ( + 'initial lock', + 'add to position' + ) + GROUP BY + A.lock_id, + A.currency, + A.decimal +), +combine AS ( + SELECT + block_id, + block_timestamp, + address, + lock_id, + amount, + currency, + DECIMAL, + _inserted_timestamp + FROM + all_staked + UNION ALL + SELECT + A.block_id, + block_timestamp, + address, + b.lock_id, + -1 * b.amount, + b.currency, + b.decimal, + _inserted_timestamp + FROM + undel_base A + LEFT JOIN unpool_lock_val C + ON A.tx_id = C.tx_id + JOIN undel_bal b + ON COALESCE( + A.lock_id, + C.lock_id + ) = b.lock_id +) +SELECT + block_id, + block_timestamp, + 'locked liquidity' AS balance_type, + address, + lock_id, + currency, + DECIMAL, + SUM(amount) over( + PARTITION BY address, + currency, + lock_id + ORDER BY + block_timestamp ASC rows unbounded preceding + ) AS balance, + concat_ws( + '-', + block_id, + address, + lock_id, + currency + ) AS _unique_key, + _inserted_timestamp +FROM + combine diff --git a/models/silver/silver__locked_liquidity_balances.yml b/models/silver/silver__locked_liquidity_balances.yml new file mode 100644 index 0000000..9678e65 --- /dev/null +++ b/models/silver/silver__locked_liquidity_balances.yml @@ -0,0 +1,56 @@ +version: 2 +models: + - name: silver__locked_liquidity_balances + description: A table of each locked liquidity balance change for wallets on the Osmosis chain. + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - ADDRESS + - BLOCK_ID + - LOCK_ID + - CURRENCY + - compare_model_subset: + name: silver__locked_liquidity_balances_business_logic_test + compare_model: ref('testing__locked_liquidity_balances') + compare_columns: + - block_id + - balance_type + - address + - lock_id + - currency + - balance + model_condition: "where block_timestamp::date = '2022-10-20' + and block_ID IN (6532496,6532489,6532483,6532481,6532478,6532477,6532468,6532463,6532461, + 6532457,6532456,6532454,6532451,6532445,6532440,6532438,6532433)" + columns: + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + tests: + - not_null + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - not_null + - name: ADDRESS + description: "{{ doc('address') }}" + tests: + - not_null + - name: LOCK_ID + description: "{{ doc('lock_id') }}" + tests: + - not_null + - name: BALANCE + description: The amount of the currency the wallet held at the given time + tests: + - not_null + - name: CURRENCY + description: "{{ doc('currency') }}" + tests: + - not_null + - name: DECIMAL + description: "{{ doc('decimal') }}" + - name: _INSERTED_TIMESTAMP + description: "{{ doc('ingested_at') }}" + tests: + - not_null + \ No newline at end of file diff --git a/models/silver/silver__locked_liquidity_transactions.sql b/models/silver/silver__locked_liquidity_transactions.sql new file mode 100644 index 0000000..d00d015 --- /dev/null +++ b/models/silver/silver__locked_liquidity_transactions.sql @@ -0,0 +1,43 @@ +{{ config( + materialized = 'incremental', + unique_key = "_unique_key", + incremental_strategy = 'merge', + cluster_by = ['_inserted_timestamp::DATE'] +) }} + +SELECT + DISTINCT tx_id, + msg_group, + msg_sub_group, + attribute_value AS lock_id, + _inserted_timestamp, + concat_ws( + '-', + A.tx_id, + COALESCE( + A.msg_group, + -1 + ), + COALESCE( + A.msg_sub_group, + -1 + ) + ) AS _unique_key +FROM + {{ ref('silver__msg_attributes') }} A +WHERE + attribute_key IN ( + 'period_lock_id', + 'lock_id' + ) + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} +) +{% endif %} diff --git a/models/silver/silver__locked_liquidity_transactions.yml b/models/silver/silver__locked_liquidity_transactions.yml new file mode 100644 index 0000000..13b2188 --- /dev/null +++ b/models/silver/silver__locked_liquidity_transactions.yml @@ -0,0 +1,28 @@ +version: 2 +models: + - name: silver__locked_liquidity_transactions + description: helper table for locked LPs + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_GROUP + - MSG_SUB_GROUP + - LOCK_ID + columns: + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - name: MSG_GROUP + description: "{{ doc('msg_group') }}" + tests: + - not_null + - name: MSG_SUB_GROUP + description: "{{ doc('msg_sub_group') }}" + tests: + - not_null + - name: LOCK_ID + description: "{{ doc('lock_id') }}" + tests: + - not_null \ No newline at end of file diff --git a/models/silver/silver__staked_balances.sql b/models/silver/silver__staked_balances.sql index f22e7d4..4818e20 100644 --- a/models/silver/silver__staked_balances.sql +++ b/models/silver/silver__staked_balances.sql @@ -1,85 +1,77 @@ {{ config( - materialized = 'incremental', - incremental_strategy = 'delete+insert', - cluster_by = ['block_timestamp'], + materialized = 'incremental', + incremental_strategy = 'delete+insert', + cluster_by = ['block_timestamp'], ) }} WITH all_staked AS ( - SELECT - block_id, - block_timestamp, + + SELECT + block_id, + block_timestamp, delegator_address AS address, - amount, - currency, - CASE + amount, + currency, + CASE WHEN currency LIKE 'gamm/pool/%' THEN 18 - ELSE raw_metadata[1]:exponent - END AS decimal, + 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' + 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 - _inserted_timestamp >= ( +AND block_timestamp :: DATE >=( SELECT - MAX( - _inserted_timestamp - ) + DATEADD('day', -2, MAX(block_timestamp)) FROM - {{ this }} - ) -{% endif %} - - UNION ALL - - SELECT - block_id, - block_timestamp, - delegator_address AS address, - -amount, - currency, - CASE + {{ 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, + 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 _inserted_timestamp >= ( - SELECT - MAX( - _inserted_timestamp - ) FROM - {{ this }} + {{ 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 %} ) -{% 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, +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 \ No newline at end of file +FROM + all_staked diff --git a/models/silver/silver__superfluid_actions.sql b/models/silver/silver__superfluid_actions.sql new file mode 100644 index 0000000..324b341 --- /dev/null +++ b/models/silver/silver__superfluid_actions.sql @@ -0,0 +1,83 @@ +{{ config( + materialized = 'incremental', + unique_key = "_unique_key", + incremental_strategy = 'merge', + cluster_by = ['_inserted_timestamp::DATE'], +) }} + +SELECT + block_id, + block_timestamp, + blockchain, + chain_id, + A.tx_id, + A.tx_status, + A.msg_type, + A.msg_group, + msg :sender :: STRING AS delegator_address, + msg :coins [0] :amount :: INT AS amount, + msg :coins [0] :denom :: STRING AS currency, + msg :val_addr :: STRING AS validator_address, + COALESCE( + msg :lock_id :: INT, + b.lock_id :: INT, + msg: id :: INT + ) AS lock_id, + msg :pool_id :: INT AS pool_id, + concat_ws( + '-', + A.tx_id, + A.msg_group + ) AS _unique_key, + _inserted_timestamp +FROM + {{ ref('silver__tx_body_msgs') }} A + LEFT JOIN ( + SELECT + tx_id, + msg_group, + attribute_value AS lock_id + FROM + {{ ref('silver__msg_attributes') }} A + WHERE + msg_type IN ( + 'lock_tokens', + 'add_tokens_to_lock' + ) + AND attribute_key IN ( + 'period_lock_id', + 'lock_id' + ) + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} +) +{% endif %} +) b +ON A.tx_id = b.tx_id +AND A.msg_group = b.msg_group +WHERE + msg_type IN ( + '/osmosis.superfluid.MsgLockAndSuperfluidDelegate', + '/osmosis.superfluid.MsgSuperfluidUndelegate', + '/osmosis.superfluid.MsgSuperfluidDelegate', + '/osmosis.superfluid.MsgUnPoolWhitelistedPool' + ) + AND tx_status = 'SUCCEEDED' + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} +) +{% endif %} diff --git a/models/silver/silver__superfluid_actions.yml b/models/silver/silver__superfluid_actions.yml new file mode 100644 index 0000000..4a5b29d --- /dev/null +++ b/models/silver/silver__superfluid_actions.yml @@ -0,0 +1,80 @@ +version: 2 +models: + - name: silver__superfluid_actions + description: "Records of all superfluid related actions" + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_GROUP + 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: 2 + - 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: MSG_TYPE + description: "{{ doc('msg_type') }}" + 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') }}" + tests: + - dbt_expectations.expect_column_values_to_be_in_type_list: + column_type_list: + - NUMBER + - FLOAT + - name: CURRENCY + description: "{{ doc('currency') }}" + - name: VALIDATOR_ADDRESS + description: "{{ doc('validator_address') }}" + - name: LOCK_ID + description: An ID corresponding to the locking step of the transaction. + - 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 diff --git a/models/silver/silver__superfluid_staked_balances.sql b/models/silver/silver__superfluid_staked_balances.sql new file mode 100644 index 0000000..2604af7 --- /dev/null +++ b/models/silver/silver__superfluid_staked_balances.sql @@ -0,0 +1,71 @@ +{{ config( + materialized = 'incremental', + unique_key = "_unique_key", + incremental_strategy = 'merge', + cluster_by = ['block_timestamp::DATE'], +) }} + +WITH super AS ( + + SELECT + block_id, + delegator_address AS address, + lock_id + FROM + {{ ref('silver__superfluid_staking') }} + s + +{% if is_incremental() %} +WHERE + block_timestamp :: DATE >=( + SELECT + DATEADD('day', -2, MAX(block_timestamp)) + FROM + {{ this }}) + {% endif %} + ), + lp_balances AS ( + SELECT + A.block_id, + A.block_timestamp, + A.address, + A.balance, + A.currency, + A.decimal, + A.lock_id, + _inserted_timestamp + FROM + {{ ref('silver__locked_liquidity_balances') }} A + JOIN super b + ON A.block_id = b.block_id + AND A.address = b.address + AND A.lock_id = b.lock_id + +{% if is_incremental() %} +WHERE + block_timestamp :: DATE >=( + SELECT + DATEADD('day', -2, MAX(block_timestamp)) + FROM + {{ this }}) + {% endif %} + ) +SELECT + block_id, + block_timestamp, + 'superfluid staked' AS balance_type, + address, + lock_id, + currency, + DECIMAL, + balance, + concat_ws( + '-', + block_id, + address, + lock_id, + currency + ) AS _unique_key, + _inserted_timestamp +FROM + lp_balances diff --git a/models/silver/silver__superfluid_staked_balances.yml b/models/silver/silver__superfluid_staked_balances.yml new file mode 100644 index 0000000..8dc7cb6 --- /dev/null +++ b/models/silver/silver__superfluid_staked_balances.yml @@ -0,0 +1,46 @@ +version: 2 +models: + - name: silver__superfluid_staked_balances + description: A table of each superfluid staked balance change for wallets on the Osmosis chain. + tests: + - compare_model_subset: + name: silver__superfluid_staked_balances_business_logic_test + compare_model: ref('testing__superfluid_staked_balances') + compare_columns: + - block_id + - balance_type + - address + - lock_id + - currency + - balance + model_condition: "where block_timestamp::date = '2022-10-18' + and block_ID IN (6503532,6503516,6503500,6503499,6503494,6503478,6503466,6503466,6503459,6503453, + 6503420,6503420,6503395,6503391,6503389,6503385,6503379,6503375,6503338)" + columns: + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + tests: + - not_null + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - not_null + - name: ADDRESS + description: "{{ doc('address') }}" + tests: + - not_null + - name: BALANCE + description: The amount of the currency the wallet held at the given time + tests: + - not_null + - name: CURRENCY + description: "{{ doc('currency') }}" + tests: + - not_null + - name: DECIMAL + description: "{{ doc('decimal') }}" + - name: _INSERTED_TIMESTAMP + description: "{{ doc('ingested_at') }}" + tests: + - not_null + \ No newline at end of file diff --git a/models/silver/silver__superfluid_staking.sql b/models/silver/silver__superfluid_staking.sql index 79f6f4d..5f5641f 100644 --- a/models/silver/silver__superfluid_staking.sql +++ b/models/silver/silver__superfluid_staking.sql @@ -2,7 +2,7 @@ materialized = 'incremental', unique_key = "_unique_key", incremental_strategy = 'merge', - cluster_by = ['block_timestamp::DATE'], + cluster_by = ['block_timestamp::DATE'] ) }} WITH @@ -21,198 +21,136 @@ max_date AS ( base_txn AS ( SELECT - top 100 block_ID, - block_timestamp, - blockchain, - chain_id, - tx_id, - tx_status, - VALUE AS actio, - REPLACE(LEFT(path, CHARINDEX(path, ']')), '[') AS msg_group, - this :sender AS delegator_address, - this :coins [0] :amount AS amount, - this :coins [0] :denom AS currency, - this :val_addr AS validator_address, - this :duration, - _inserted_timestamp, - this :lock_id AS lock_id - FROM - {{ ref('silver__transactions') }} A, - LATERAL FLATTEN ( - input => tx_body :messages, - recursive => TRUE - ) b - WHERE - key = '@type' - AND VALUE :: STRING IN ( - '/osmosis.superfluid.MsgLockAndSuperfluidDelegate', - '/osmosis.superfluid.MsgSuperfluidUndelegate', - '/osmosis.superfluid.MsgSuperfluidDelegate', - '/osmosis.superfluid.MsgUnPoolWhitelistedPool' - ) - AND tx_status = 'SUCCEEDED' - -{% if is_incremental() %} -AND _inserted_timestamp >= ( - SELECT - MAX( - _inserted_timestamp - ) - FROM - max_date -) -{% endif %} -), -locks AS ( - SELECT - b.tx_ID ub_tx_id, - A.tx_ID, - attribute_value lock_id - FROM - {{ ref('silver__msg_attributes') }} A - JOIN ( - SELECT - DISTINCT lock_id, - tx_id - FROM - base_txn - ) b - ON b.lock_id = A.attribute_value - WHERE - msg_type IN ( - 'lock_tokens', - 'add_tokens_to_lock' - ) - AND attribute_key LIKE '%lock%' - -{% if is_incremental() %} -AND _inserted_timestamp >= ( - SELECT - MAX( - _inserted_timestamp - ) - FROM - max_date -) -{% endif %} -), -lock_body AS ( - SELECT - b.ub_tx_id, - b.lock_ID, + A.block_id, + A.block_timestamp, + A.blockchain, + A.chain_id, A.tx_id, - this :coins [0] :amount AS amount, - this :coins [0] :denom AS currecy, - this :val_addr AS validator_address, - this :duration, - this + A.tx_status, + A.msg_group, + A.msg_type, + A.msg_action_description, + A.locker_address, + A.lock_id, + A.amount, + A.currency, + A.decimal, + A.pool_id, + A.lock_duration, + A.unlock_time, + A.unpool_new_lock_ids, + A._unique_key, + A._inserted_timestamp FROM - {{ ref('silver__transactions') }} A, - locks b, - LATERAL FLATTEN ( - input => tx_body :messages, - recursive => TRUE - ) C + {{ ref('silver__locked_liquidity_actions') }} A WHERE - A.tx_id = b.tx_ID - AND key = '@type' - AND VALUE :: STRING IN ( - '/osmosis.superfluid.MsgLockAndSuperfluidDelegate', - '/osmosis.superfluid.MsgSuperfluidDelegate' - ) + is_superfluid = TRUE {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX( - _inserted_timestamp - ) + _inserted_timestamp FROM max_date ) {% endif %} ), -tx_address AS ( +vals 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 + lock_id, + validator_address FROM - {{ ref('silver__msg_attributes') }} A - JOIN ( - SELECT - DISTINCT tx_id - FROM - base_txn - ) b - ON A.tx_ID = b.tx_ID + {{ ref('silver__superfluid_actions') }} A WHERE - attribute_key = 'acc_seq' + validator_address IS NOT NULL {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT - MAX( - _inserted_timestamp - ) + _inserted_timestamp FROM max_date ) {% endif %} -GROUP BY - A.tx_id, - msg_group + +qualify(ROW_NUMBER() over(PARTITION BY lock_id +ORDER BY + block_id DESC) = 1) +), +unpool_lock_val AS ( + SELECT + A.lock_id, + A.currency, + A.delegator_address, + A.validator_address + FROM + {{ ref('silver__superfluid_actions') }} A + JOIN {{ ref('silver__locked_liquidity_actions') }} + b + ON b.msg_action_description = 'unpool' + AND A.delegator_address = b.locker_address + AND A.currency = b.currency + AND A.block_id < b.block_id + WHERE + validator_address IS NOT NULL + +{% if is_incremental() %} +AND A._inserted_timestamp >= ( + SELECT + _inserted_timestamp + FROM + max_date +) +{% endif %} + +qualify(ROW_NUMBER() over(PARTITION BY A.lock_id +ORDER BY + A.block_id DESC) = 1) ) SELECT A.block_id, A.block_timestamp, A.blockchain, - chain_ID, - A.tx_ID, + chain_id, + A.tx_id, + A.msg_group, A.tx_status, - tx.tx_caller_address, - REPLACE( - A.actio :: STRING, - '/osmosis.superfluid.Msg' - ) action, - A.delegator_address :: STRING AS delegator_address, - COALESCE( - A.amount :: INT, - C.amount :: INT - ) AS amount, - A.currency :: STRING AS currency, + {# msg_action_description, #} CASE - WHEN A.currency LIKE 'gamm/pool/%' THEN 18 - ELSE am.raw_metadata [1] :exponent - END AS DECIMAL, + msg_action_description + WHEN 'initial lock' THEN 'delegate' + WHEN 'add to position' THEN 'delegate' + WHEN 'unlock' THEN 'undelegate' + WHEN 'unpool' THEN 'undelegate' + END AS action, + A.locker_address AS delegator_address, + A.amount, + A.currency, + A.decimal, COALESCE( - A.validator_address :: STRING, - C.validator_address :: STRING + b.validator_address, + C.validator_address ) AS validator_address, COALESCE( A.lock_id, C.lock_id - ) AS lock_ID, - C.tx_ID AS original_superfluid_delegate_tx_ID, + ) AS lock_id, _inserted_timestamp, concat_ws( '-', A.tx_id, - action + A.msg_group, + COALESCE( + A.lock_id, + -1 + ), + msg_action_description ) AS _unique_key FROM base_txn A - LEFT JOIN lock_body C - ON A.tx_id = C.ub_tx_ID - LEFT JOIN tx_address tx - ON A.tx_id = tx.tx_id - LEFT JOIN {{ ref('silver__asset_metadata') }} - am - ON A.currency = am.address + LEFT JOIN vals b + ON A.lock_id = b.lock_id + LEFT JOIN unpool_lock_val C + ON A.locker_address = C.delegator_address + AND A.currency = C.currency + AND A.msg_action_description = 'unpool' diff --git a/models/silver/silver__superfluid_staking.yml b/models/silver/silver__superfluid_staking.yml index da79c07..7ccebb3 100644 --- a/models/silver/silver__superfluid_staking.yml +++ b/models/silver/silver__superfluid_staking.yml @@ -6,6 +6,8 @@ models: - dbt_utils.unique_combination_of_columns: combination_of_columns: - TX_ID + - MSG_GROUP + - LOCK_ID - ACTION columns: - name: BLOCK_ID @@ -42,10 +44,6 @@ models: 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: @@ -69,12 +67,8 @@ models: description: "{{ doc('currency') }}" - name: VALIDATOR_ADDRESS description: "{{ doc('validator_address') }}" - - name: DECIMAL - description: "{{ doc('decimal') }}" - name: LOCK_ID - description: An ID corresponding to the locking step of the transaction. - - name: ORIGINAL_SUPERFLUID_DELEGATE_TX_ID - description: The transaction id when the user initialized the superfluid stake. + description: "{{ doc('lock_id') }}" - name: _INSERTED_TIMESTAMP description: "{{ doc('inserted_timestamp') }}" tests: diff --git a/models/silver/silver__tx_body_msgs.sql b/models/silver/silver__tx_body_msgs.sql new file mode 100644 index 0000000..3b03f31 --- /dev/null +++ b/models/silver/silver__tx_body_msgs.sql @@ -0,0 +1,56 @@ +{{ config( + materialized = 'incremental', + unique_key = "_unique_key", + incremental_strategy = 'merge', + cluster_by = ['_inserted_timestamp::DATE'] +) }} + +WITH b AS ( + + SELECT + block_id, + block_timestamp, + blockchain, + chain_id, + tx_id, + tx_status, + INDEX AS msg_group, + VALUE :"@type" :: STRING AS msg_type, + VALUE AS msg, + _inserted_timestamp + FROM + {{ ref('silver__transactions') }} A, + LATERAL FLATTEN( + input => A.tx_body :messages + ) + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX( + _inserted_timestamp + ) + FROM + {{ this }} + ) +{% endif %} +) +SELECT + block_id, + block_timestamp, + blockchain, + chain_id, + tx_id, + tx_status, + msg_group, + msg_type, + msg, + concat_ws( + '-', + tx_id, + msg_group + ) AS _unique_key, + _inserted_timestamp +FROM + b diff --git a/models/silver/silver__tx_body_msgs.yml b/models/silver/silver__tx_body_msgs.yml new file mode 100644 index 0000000..922a7bd --- /dev/null +++ b/models/silver/silver__tx_body_msgs.yml @@ -0,0 +1,57 @@ +version: 2 +models: + - name: silver__tx_body_msgs + description: Records of all messages associated to transactions that have occurred on Osmosis, dating back to the genesis block. + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_GROUP + 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: CHAIN_ID + description: "{{ doc('chain_id') }}" + tests: + - not_null + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - 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: MSG_TYPE + description: "{{ doc('msg_type') }}" + tests: + - not_null + - name: MSG + description: "The underlying json from the message or event within the transactions" + - 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