diff --git a/models/bronze/bronze_api/bronze_api__get_seaswap_pools.sql b/models/bronze/bronze_api/bronze_api__get_seaswap_pools.sql index a01ee19..cc094bc 100644 --- a/models/bronze/bronze_api/bronze_api__get_seaswap_pools.sql +++ b/models/bronze/bronze_api/bronze_api__get_seaswap_pools.sql @@ -1,7 +1,7 @@ {{ config( materialized = 'incremental', full_refresh = false, - enabled = false + enabled = true ) }} WITH perms AS ( diff --git a/models/descriptions/amount_in.md b/models/descriptions/amount_in.md new file mode 100644 index 0000000..9bd0db4 --- /dev/null +++ b/models/descriptions/amount_in.md @@ -0,0 +1,5 @@ +{% docs amount_in %} + +The amount that was sent into the swap transaction. + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/amount_out.md b/models/descriptions/amount_out.md new file mode 100644 index 0000000..92a715b --- /dev/null +++ b/models/descriptions/amount_out.md @@ -0,0 +1,5 @@ +{% docs amount_out %} + +The amount that was received from the swap transaction. + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/currency_in.md b/models/descriptions/currency_in.md new file mode 100644 index 0000000..02d83ea --- /dev/null +++ b/models/descriptions/currency_in.md @@ -0,0 +1,5 @@ +{% docs currency_in %} + +The currency that was sent into the swap transaction. + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/currency_out.md b/models/descriptions/currency_out.md new file mode 100644 index 0000000..51387f6 --- /dev/null +++ b/models/descriptions/currency_out.md @@ -0,0 +1,5 @@ +{% docs currency_out %} + +The currency that was received from the swap transaction. + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/liquidity_provider_address.md b/models/descriptions/liquidity_provider_address.md new file mode 100644 index 0000000..c6afac4 --- /dev/null +++ b/models/descriptions/liquidity_provider_address.md @@ -0,0 +1,5 @@ +{% docs liquidity_provider_address %} + +The address that took an action on the pool. + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/lp_action.md b/models/descriptions/lp_action.md new file mode 100644 index 0000000..9ae4d25 --- /dev/null +++ b/models/descriptions/lp_action.md @@ -0,0 +1,5 @@ +{% docs lp_action %} + +The action that the liquidity provider took. The value is one of the following: add_liquidity,remove_liquidity + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/lp_token_address.md b/models/descriptions/lp_token_address.md new file mode 100644 index 0000000..63f9750 --- /dev/null +++ b/models/descriptions/lp_token_address.md @@ -0,0 +1,5 @@ +{% docs lp_token_address %} + +The address of LP tokens that were added, removed, bonded, or unbonded from the pool. + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/lp_token_amount.md b/models/descriptions/lp_token_amount.md new file mode 100644 index 0000000..1b353fc --- /dev/null +++ b/models/descriptions/lp_token_amount.md @@ -0,0 +1,5 @@ +{% docs lp_token_amount %} + +The amount of LP tokens that were added, removed, bonded, or unbonded from the pool. + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/pool_address.md b/models/descriptions/pool_address.md new file mode 100644 index 0000000..222061d --- /dev/null +++ b/models/descriptions/pool_address.md @@ -0,0 +1,5 @@ +{% docs pool_address %} + +Address of the pool + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/pool_name.md b/models/descriptions/pool_name.md new file mode 100644 index 0000000..c8a2de3 --- /dev/null +++ b/models/descriptions/pool_name.md @@ -0,0 +1,5 @@ +{% docs pool_name %} + +The name of the pool + +{% enddocs %} \ No newline at end of file diff --git a/models/descriptions/swapper.md b/models/descriptions/swapper.md new file mode 100644 index 0000000..6a83998 --- /dev/null +++ b/models/descriptions/swapper.md @@ -0,0 +1,5 @@ +{% docs swapper %} + +The wallet address of the individual who initiated the swap. + +{% enddocs %} \ No newline at end of file diff --git a/models/gold/defi/defi__fact_dex_swaps.sql b/models/gold/defi/defi__fact_dex_swaps.sql new file mode 100644 index 0000000..ecebcdb --- /dev/null +++ b/models/gold/defi/defi__fact_dex_swaps.sql @@ -0,0 +1,64 @@ +{{ config( + materialized = 'view', + meta ={ 'database_tags':{ 'table':{ 'PURPOSE': 'SWAPS' }} } +) }} + +SELECT + 'astroport' AS platform, + block_id, + block_timestamp, + tx_succeeded, + tx_id, + swapper, + msg_group, + msg_sub_group, + msg_index, + amount_in, + currency_in, + amount_out, + currency_out, + pool_address, + pool_name, + _inserted_timestamp +FROM + {{ ref('silver__dex_swaps_astroport') }} +UNION ALL +SELECT + 'fuzio' AS platform, + block_id, + block_timestamp, + tx_succeeded, + tx_id, + swapper, + msg_group, + msg_sub_group, + msg_index, + amount_in, + currency_in, + amount_out, + currency_out, + pool_address, + pool_name, + _inserted_timestamp +FROM + {{ ref('silver__dex_swaps_fuzio') }} +UNION ALL +SELECT + 'seaswap' AS platform, + block_id, + block_timestamp, + tx_succeeded, + tx_id, + swapper, + msg_group, + msg_sub_group, + msg_index, + amount_in, + currency_in, + amount_out, + currency_out, + pool_address, + pool_name, + _inserted_timestamp +FROM + {{ ref('silver__dex_swaps_seaswap') }} diff --git a/models/gold/defi/defi__fact_dex_swaps.yml b/models/gold/defi/defi__fact_dex_swaps.yml new file mode 100644 index 0000000..28f7a6a --- /dev/null +++ b/models/gold/defi/defi__fact_dex_swaps.yml @@ -0,0 +1,33 @@ +version: 2 +models: + - name: defi__fact_dex_swaps + description: Records swap transactions on Sei for Astroport, Fuzio, and Seaswap + columns: + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + - name: TX_ID + description: "{{ doc('tx_id') }}" + - name: TX_SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + - name: SWAPPER + description: "{{ doc('swapper') }}" + - name: MSG_GROUP + description: "{{ doc('msg_group') }}" + - name: MSG_SUB_GROUP + description: "{{ doc('msg_sub_group') }}" + - name: MSG_INDEX + description: "{{ doc('msg_index') }}" + - name: AMOUNT_IN + description: "{{ doc('amount_in') }}" + - name: CURRENCY_IN + description: "{{ doc('currency_in') }}" + - name: AMOUNT_OUT + description: "{{ doc('amount_out') }}" + - name: CURRENCY_out + description: "{{ doc('currency_out') }}" + - name: POOL_ADDRESS + description: "{{ doc('pool_address') }}" + - name: POOL_NAME + description: "{{ doc('pool_name') }}" diff --git a/models/silver/defi/dex/silver__dex_metadata_seaswap.sql b/models/silver/defi/dex/silver__dex_metadata_seaswap.sql index 45b5d49..9ce297c 100644 --- a/models/silver/defi/dex/silver__dex_metadata_seaswap.sql +++ b/models/silver/defi/dex/silver__dex_metadata_seaswap.sql @@ -2,7 +2,7 @@ materialized = 'incremental', unique_key = 'pool_id', incremental_strategy = 'merge', - enabled = false + enabled = true ) }} SELECT diff --git a/models/silver/defi/dex/silver__dex_swaps_astroport.sql b/models/silver/defi/dex/silver__dex_swaps_astroport.sql index 9bf856b..e1c2fd0 100644 --- a/models/silver/defi/dex/silver__dex_swaps_astroport.sql +++ b/models/silver/defi/dex/silver__dex_swaps_astroport.sql @@ -2,8 +2,7 @@ materialized = 'incremental', unique_key = ['tx_id','msg_index'], incremental_strategy = 'merge', - cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ], - enabled = false + cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ] ) }} WITH rel_contracts AS ( @@ -147,8 +146,11 @@ SELECT maker_fee_amount, spread_amount, _contract_address AS pool_address, + C.pool_name, A._inserted_timestamp FROM wasm A JOIN fee_payer b ON A.tx_id = b.tx_id + JOIN rel_contracts C + ON A._contract_address = C.contract_address diff --git a/models/silver/defi/dex/silver__dex_swaps_astroport.yml b/models/silver/defi/dex/silver__dex_swaps_astroport.yml new file mode 100644 index 0000000..a13b4a0 --- /dev/null +++ b/models/silver/defi/dex/silver__dex_swaps_astroport.yml @@ -0,0 +1,67 @@ +version: 2 +models: + - name: silver__dex_swaps_astroport + description: Records of swaps that occurred on the Astroport platform + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_INDEX + columns: + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 1 + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - name: TX_SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + tests: + - not_null + - name: SWAPPER + description: "{{ doc('swapper') }}" + 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: MSG_INDEX + description: "{{ doc('msg_index') }}" + tests: + - not_null + - name: AMOUNT_IN + description: "{{ doc('amount_in') }}" + tests: + - not_null + - name: CURRENCY_IN + description: "{{ doc('currency_in') }}" + tests: + - not_null + - name: AMOUNT_OUT + description: "{{ doc('amount_out') }}" + tests: + - not_null + - name: CURRENCY_out + description: "{{ doc('currency_out') }}" + tests: + - not_null + - name: POOL_ADDRESS + description: "{{ doc('pool_address') }}" + tests: + - not_null + - name: POOL_NAME + description: "{{ doc('pool_name') }}" + tests: + - not_null + diff --git a/models/silver/defi/dex/silver__dex_swaps_fuzio.sql b/models/silver/defi/dex/silver__dex_swaps_fuzio.sql index 7287793..781fc00 100644 --- a/models/silver/defi/dex/silver__dex_swaps_fuzio.sql +++ b/models/silver/defi/dex/silver__dex_swaps_fuzio.sql @@ -3,7 +3,7 @@ unique_key = ['tx_id','msg_index'], incremental_strategy = 'merge', cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ], - enabled = false + enabled = true ) }} WITH rel_contracts AS ( diff --git a/models/silver/defi/dex/silver__dex_swaps_fuzio.yml b/models/silver/defi/dex/silver__dex_swaps_fuzio.yml index 27fc5f8..ca89619 100644 --- a/models/silver/defi/dex/silver__dex_swaps_fuzio.yml +++ b/models/silver/defi/dex/silver__dex_swaps_fuzio.yml @@ -1,11 +1,12 @@ version: 2 models: - name: silver__dex_swaps_fuzio - description: Records of all transactions that have occurred on Sei, dating back to the genesis block + description: Records of swaps that occurred on the Fuzio platform tests: - dbt_utils.unique_combination_of_columns: combination_of_columns: - TX_ID + - MSG_INDEX columns: - name: BLOCK_ID description: "{{ doc('block_id') }}" @@ -17,20 +18,50 @@ models: interval: 1 - name: TX_ID description: "{{ doc('tx_id') }}" - - name: TX_SUCCEEDED - description: "{{ doc('tx_succeeded') }}" - - name: CODESPACE - description: "{{ doc('codespace') }}" - - name: FEE - description: "{{ doc('fee') }}" tests: - not_null - - name: GAS_USED - description: "{{ doc('gas_used') }}" - - name: GAS_WANTED - description: "{{ doc('gas_wanted') }}" - - name: TX_CODE - description: "{{ doc('tx_code') }}" - - name: MSGS - description: "{{ doc('msgs') }}" + - name: TX_SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + tests: + - not_null + - name: SWAPPER + description: "{{ doc('swapper') }}" + 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: MSG_INDEX + description: "{{ doc('msg_index') }}" + tests: + - not_null + - name: AMOUNT_IN + description: "{{ doc('amount_in') }}" + tests: + - not_null + - name: CURRENCY_IN + description: "{{ doc('currency_in') }}" + tests: + - not_null + - name: AMOUNT_OUT + description: "{{ doc('amount_out') }}" + tests: + - not_null + - name: CURRENCY_out + description: "{{ doc('currency_out') }}" + tests: + - not_null + - name: POOL_ADDRESS + description: "{{ doc('pool_address') }}" + tests: + - not_null + - name: POOL_NAME + description: "{{ doc('pool_name') }}" + tests: + - not_null diff --git a/models/silver/defi/dex/silver__dex_swaps_seaswap.sql b/models/silver/defi/dex/silver__dex_swaps_seaswap.sql index 75baaa0..be4d1e8 100644 --- a/models/silver/defi/dex/silver__dex_swaps_seaswap.sql +++ b/models/silver/defi/dex/silver__dex_swaps_seaswap.sql @@ -2,19 +2,16 @@ materialized = 'incremental', unique_key = ['tx_id','msg_index'], incremental_strategy = 'merge', - cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ], - enabled = false + cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ] ) }} WITH rel_contracts AS ( SELECT - contract_address, - label AS pool_name + pool_address AS contract_address, + pool_name FROM - {{ ref('silver__contracts') }} - WHERE - label ILIKE '%seaswap%pool%' + {{ ref('silver__dex_metadata_seaswap') }} ), all_txns AS ( SELECT @@ -30,7 +27,8 @@ all_txns AS ( attribute_value, _inserted_timestamp FROM - {{ ref('silver__msg_attributes') }} A + {{ ref('silver__msg_attributes') }} A {# WHERE + block_timestamp :: DATE = '2023-08-24' #} {% if is_incremental() %} WHERE @@ -44,28 +42,23 @@ WHERE ), rel_txns AS ( SELECT - tx_id, - block_timestamp, - msg_group, - msg_sub_group + tx_id FROM all_txns A JOIN rel_contracts b ON A.attribute_value = b.contract_address WHERE msg_type = 'execute' - AND attribute_key = '_contract_address' {# INTERSECT + AND attribute_key = '_contract_address' {# + INTERSECT SELECT - tx_id, - block_timestamp, - msg_group, - msg_sub_group + tx_id FROM all_txns A WHERE msg_type = 'wasm' AND attribute_key = 'action' - AND attribute_value = 'swap' #} + AND attribute_value = 'transfer' #} ), fee_payer AS ( SELECT @@ -98,9 +91,13 @@ wasm AS ( attribute_key :: STRING, attribute_value :: variant ) AS j, - j :_contract_address :: STRING AS _contract_address, + j :_contract_address :: STRING AS contract_address, j :native_sold :: INT AS native_sold, - j :token_bought :: INT AS token_bought + j :token_bought :: INT AS token_bought, + j :action :: STRING AS action, + j :amount :: INT AS amount, + j :from :: STRING AS x_from, + j :to :: STRING AS x_to FROM all_txns A JOIN fee_payer b @@ -134,7 +131,19 @@ xfers AS ( ) AS j, j :sender :: STRING AS sender, j :recipient :: STRING AS recipient, - j :amount :: STRING AS amount + j :amount :: STRING AS amount_raw, + SPLIT_PART( + TRIM( + REGEXP_REPLACE( + amount_raw, + '[^[:digit:]]', + ' ' + ) + ), + ' ', + 0 + ) :: INT AS amount, + RIGHT(amount_raw, LENGTH(amount_raw) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(amount_raw, '[^[:digit:]]', ' ')), ' ', 0))) AS currency FROM all_txns A JOIN fee_payer b @@ -154,10 +163,54 @@ xfers AS ( ), combo AS ( SELECT - * + A.*, + b.tx_fee_payer, + x_in.amount AS amount_in, + x_in.currency AS currency_in, + COALESCE( + x_out.amount, + wasm_out.amount + ) AS amount_out, + COALESCE( + x_out.currency, + wasm_out.contract_address + ) AS currency_out {# , + x_fee.amount AS amount_fee, + x_fee.currency AS currency_fee #} FROM wasm A - JOIN + JOIN fee_payer b + ON A.tx_id = b.tx_id + JOIN xfers x_in + ON A.tx_id = x_in.tx_id + AND A.msg_group = x_in.msg_group + AND A.msg_sub_group = x_in.msg_sub_group + AND A.native_sold = x_in.amount + AND b.tx_fee_payer = x_in.sender + LEFT JOIN xfers x_out + ON A.tx_id = x_out.tx_id + AND A.msg_group = x_out.msg_group + AND A.msg_sub_group = x_out.msg_sub_group + AND A.token_bought = x_out.amount + AND b.tx_fee_payer = x_out.recipient + LEFT JOIN wasm wasm_out + ON wasm_out.action = 'transfer' + AND A.tx_id = wasm_out.tx_id + AND A.msg_group = wasm_out.msg_group + AND A.msg_sub_group = wasm_out.msg_sub_group + AND A.token_bought = wasm_out.amount + AND b.tx_fee_payer = wasm_out.x_to {# JOIN xfers x_fee + ON A.tx_id = x_fee.tx_id + AND A.msg_group = x_fee.msg_group + AND A.msg_sub_group = x_fee.msg_sub_group + AND x_in.tx_id IS NULL + AND x_out.tx_id IS NULL #} + WHERE + A.native_sold IS NOT NULL + AND COALESCE( + x_out.amount, + wasm_out.amount + ) IS NOT NULL ) SELECT A.block_id, @@ -168,39 +221,17 @@ SELECT A.msg_group, A.msg_sub_group, A.msg_index, - {# A.sender, - A.recipient, + A.amount_in, + A.currency_in, + A.amount_out, + A.currency_out, + {# A.amount_fee, + A.currency_fee, #} - A.amount_in AS ain_raw, - SPLIT_PART( - TRIM( - REGEXP_REPLACE( - amount_in, - '[^[:digit:]]', - ' ' - ) - ), - ' ', - 0 - ) AS amount_in, - RIGHT(amount_in, LENGTH(amount_in) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(amount_in, '[^[:digit:]]', ' ')), ' ', 0))) AS currency_in, - A.amount_out aou_raw, - SPLIT_PART( - TRIM( - REGEXP_REPLACE( - amount_out, - '[^[:digit:]]', - ' ' - ) - ), - ' ', - 0 - ) AS amount_out, - RIGHT(amount_out, LENGTH(amount_out) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(amount_out, '[^[:digit:]]', ' ')), ' ', 0))) AS currency_out, - A.pool_address, + A.contract_address AS pool_address, b.pool_name, A._inserted_timestamp FROM - fin A + combo A LEFT JOIN rel_contracts b - ON A.pool_address = b.contract_address + ON A.contract_address = b.contract_address diff --git a/models/silver/defi/dex/silver__dex_swaps_seaswap.yml b/models/silver/defi/dex/silver__dex_swaps_seaswap.yml new file mode 100644 index 0000000..1df0121 --- /dev/null +++ b/models/silver/defi/dex/silver__dex_swaps_seaswap.yml @@ -0,0 +1,67 @@ +version: 2 +models: + - name: silver__dex_swaps_seaswap + description: Records of swaps that occurred on the SeaSwap platform + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_INDEX + columns: + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 1 + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - name: TX_SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + tests: + - not_null + - name: SWAPPER + description: "{{ doc('swapper') }}" + 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: MSG_INDEX + description: "{{ doc('msg_index') }}" + tests: + - not_null + - name: AMOUNT_IN + description: "{{ doc('amount_in') }}" + tests: + - not_null + - name: CURRENCY_IN + description: "{{ doc('currency_in') }}" + tests: + - not_null + - name: AMOUNT_OUT + description: "{{ doc('amount_out') }}" + tests: + - not_null + - name: CURRENCY_out + description: "{{ doc('currency_out') }}" + tests: + - not_null + - name: POOL_ADDRESS + description: "{{ doc('pool_address') }}" + tests: + - not_null + - name: POOL_NAME + description: "{{ doc('pool_name') }}" + tests: + - not_null + diff --git a/models/silver/defi/lp/astroport/silver__lp_actions_astroport.sql b/models/silver/defi/lp/astroport/silver__lp_actions_astroport.sql new file mode 100644 index 0000000..b44cedf --- /dev/null +++ b/models/silver/defi/lp/astroport/silver__lp_actions_astroport.sql @@ -0,0 +1,207 @@ +{{ config( + materialized = 'incremental', + unique_key = ['tx_id','msg_index'], + incremental_strategy = 'merge', + cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ] +) }} + +WITH rel_contracts AS ( + + SELECT + contract_address, + label AS pool_name + FROM + {{ ref('silver__contracts') }} + WHERE + label ILIKE 'Astroport%' +), +contract_info AS ( + SELECT + contract_address, + DATA :lp_token_address :: STRING AS lp_token_address, + DATA :token1_denom :native :: STRING AS token1_currency, + DATA :token2_denom :native :: STRING AS token2_currency + FROM + {{ ref('silver__contract_info') }} +), +all_txns AS ( + SELECT + block_id, + block_timestamp, + tx_id, + tx_succeeded, + msg_group, + msg_sub_group, + msg_type, + msg_index, + attribute_key, + attribute_value, + _inserted_timestamp + FROM + {{ ref('silver__msg_attributes') }} A {# WHERE + block_timestamp :: DATE = '2023-08-23' #} + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} + ) +{% endif %} +), +rel_txns AS ( + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + JOIN rel_contracts b + ON A.attribute_value = b.contract_address + WHERE + msg_type = 'execute' + AND attribute_key = '_contract_address' + INTERSECT + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + WHERE + msg_type = 'wasm' + AND attribute_key = 'action' + AND attribute_value IN ( + 'provide_liquidity', + 'mint', + 'withdraw_liquidity', + 'burn' + ) +), +wasm AS ( + SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp, + OBJECT_AGG( + attribute_key :: STRING, + attribute_value :: variant + ) AS j, + j :_contract_address :: STRING AS contract_address, + j :action :: STRING AS action, + j :sender :: STRING AS sender, + j :receiver :: STRING AS receiver, + j :assets :: STRING AS assets, + j :refund_assets :: STRING AS refund_assets, + j :share :: INT AS SHARE, + j :withdrawn_share :: INT AS withdrawn_share, + j :amount :: INT AS amount, + SPLIT_PART(COALESCE(assets, refund_assets), ',', 1) AS token1_raw, + SUBSTRING( + SPLIT_PART(COALESCE(assets, refund_assets), ',', 2), + 2, + 9999 + ) AS token2_raw, + SPLIT_PART( + TRIM( + REGEXP_REPLACE( + token1_raw, + '[^[:digit:]]', + ' ' + ) + ), + ' ', + 0 + ) AS token1_amount, + RIGHT(token1_raw, LENGTH(token1_raw) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(token1_raw, '[^[:digit:]]', ' ')), ' ', 0))) AS token1_currency, + SPLIT_PART( + TRIM( + REGEXP_REPLACE( + token2_raw, + '[^[:digit:]]', + ' ' + ) + ), + ' ', + 0 + ) AS token2_amount, + RIGHT(token2_raw, LENGTH(token2_raw) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(token2_raw, '[^[:digit:]]', ' ')), ' ', 0))) AS token2_currency + FROM + all_txns A + JOIN rel_txns 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 + msg_type = 'wasm' + GROUP BY + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp + HAVING + action IN ( + 'provide_liquidity', + 'mint', + 'withdraw_liquidity', + 'burn' + ) +) +SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + A.sender AS liquidity_provider_address, + A.action AS lp_action, + A.contract_address AS pool_address, + C.pool_name, + A.token1_raw, + A.token1_amount, + A.token1_currency, + A.token2_raw, + A.token2_amount, + A.token2_currency, + COALESCE( + A.share, + A.withdrawn_share + ) AS lp_token_amount, + b.contract_address AS lp_token_address, + A._inserted_timestamp +FROM + wasm A + JOIN wasm b + ON A.tx_id = b.tx_id + AND A.msg_group = b.msg_group + AND A.msg_sub_group = b.msg_sub_group + AND COALESCE( + A.share, + A.withdrawn_share + ) = b.amount + JOIN rel_contracts C + ON A.contract_address = C.contract_address +WHERE + A.action IN ( + 'provide_liquidity', + 'withdraw_liquidity' + ) + AND b.action IN ( + 'mint', + 'burn' + ) diff --git a/models/silver/defi/lp/astroport/silver__lp_actions_astroport.yml b/models/silver/defi/lp/astroport/silver__lp_actions_astroport.yml new file mode 100644 index 0000000..1a968a3 --- /dev/null +++ b/models/silver/defi/lp/astroport/silver__lp_actions_astroport.yml @@ -0,0 +1,79 @@ +version: 2 +models: + - name: silver__lp_actions_astroport + description: Records of liquidity provider that occurred on the Astroport platform + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_INDEX + columns: + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 1 + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - name: TX_SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + 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: MSG_INDEX + description: "{{ doc('msg_index') }}" + tests: + - not_null + - name: LIQUIDITY_PROVIDER_ADDRESS + description: "{{ doc('liquidity_provider_address') }}" + tests: + - not_null + - name: LP_ACTION + description: "{{ doc('lp_action') }}" + tests: + - not_null + - name: POOL_ADDRESS + description: "{{ doc('pool_address') }}" + tests: + - not_null + - name: POOL_NAME + description: "{{ doc('pool_name') }}" + tests: + - not_null + - name: TOKEN1_AMOUNT + description: "The amount of the first token provided by the liquidity provider" + tests: + - not_null + - name: TOKEN1_CURRENCY + description: "The currency of the first token provided by the liquidity provider" + tests: + - not_null + - name: TOKEN2_AMOUNT + description: "The amount of the second token provided by the liquidity provider" + tests: + - not_null + - name: TOKEN2_CURRENCY + description: "The currency of the second token provided by the liquidity provider" + tests: + - not_null + - name: LP_TOKEN_AMOUNT + description: "{{ doc('lp_token_amount') }}" + tests: + - not_null + - name: LP_TOKEN_ADDRESS + description: "{{ doc('lp_token_address') }}" + tests: + - not_null + diff --git a/models/silver/defi/lp/fuzio/silver__lp_actions_fuzio.sql b/models/silver/defi/lp/fuzio/silver__lp_actions_fuzio.sql new file mode 100644 index 0000000..46e8f65 --- /dev/null +++ b/models/silver/defi/lp/fuzio/silver__lp_actions_fuzio.sql @@ -0,0 +1,177 @@ +{{ config( + materialized = 'incremental', + unique_key = ['tx_id','msg_index'], + incremental_strategy = 'merge', + cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ] +) }} + +WITH rel_contracts AS ( + + SELECT + contract_address, + label AS pool_name + FROM + {{ ref('silver__contracts') }} + WHERE + label ILIKE 'Fuzio%' +), +contract_info AS ( + SELECT + contract_address, + DATA :lp_token_address :: STRING AS lp_token_address, + DATA :token1_denom :native :: STRING AS token1_currency, + DATA :token2_denom :native :: STRING AS token2_currency + FROM + {{ ref('silver__contract_info') }} +), +all_txns AS ( + SELECT + block_id, + block_timestamp, + tx_id, + tx_succeeded, + msg_group, + msg_sub_group, + msg_type, + msg_index, + attribute_key, + attribute_value, + _inserted_timestamp + FROM + {{ ref('silver__msg_attributes') }} A + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} + ) +{% endif %} +), +rel_txns AS ( + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + JOIN rel_contracts b + ON A.attribute_value = b.contract_address + WHERE + msg_type = 'execute' + AND attribute_key = '_contract_address' + INTERSECT + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + WHERE + msg_type = 'wasm' + AND attribute_key = 'action' + AND attribute_value IN ( + 'add_liquidity', + 'mint', + 'remove_liquidity', + 'burn_from' + ) +), +wasm AS ( + SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp, + OBJECT_AGG( + attribute_key :: STRING, + attribute_value :: variant + ) AS j, + j :_contract_address :: STRING AS contract_address, + j :action :: STRING AS action, + j :token1_amount :: INT AS token1_amount, + j :token2_amount :: INT AS token2_amount, + j :token1_returned :: INT AS token1_returned, + j :token2_returned :: INT AS token2_returned, + j :liquidity_received :: INT AS liquidity_received, + j :liquidity_burned :: INT AS liquidity_burned, + j :to :: STRING AS to_address, + j :from :: STRING AS from_address, + j :by :: STRING AS by_address, + j :amount :: INT AS amount + FROM + all_txns A + JOIN rel_txns 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 + msg_type = 'wasm' + GROUP BY + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp +) +SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + COALESCE( + b.to_address, + b.from_address + ) AS liquidity_provider_address, + A.action AS lp_action, + A.contract_address AS pool_address, + C.pool_name, + COALESCE( + A.token1_amount, + A.token1_returned + ) AS token1_amount, + d.token1_currency, + COALESCE( + A.token2_amount, + A.token2_returned + ) AS token2_amount, + d.token2_currency, + COALESCE( + A.liquidity_received, + A.liquidity_burned + ) AS lp_token_amount, + d.lp_token_address, + A._inserted_timestamp +FROM + wasm A + JOIN wasm b + ON A.tx_id = b.tx_id + AND A.msg_group = b.msg_group + AND A.msg_sub_group = b.msg_sub_group + JOIN rel_contracts C + ON A.contract_address = C.contract_address + JOIN contract_info d + ON A.contract_address = d.contract_address +WHERE + A.action IN ( + 'add_liquidity', + 'remove_liquidity' + ) + AND b.action IN ( + 'mint', + 'burn_from' + ) diff --git a/models/silver/defi/lp/fuzio/silver__lp_actions_fuzio.yml b/models/silver/defi/lp/fuzio/silver__lp_actions_fuzio.yml new file mode 100644 index 0000000..3f96de4 --- /dev/null +++ b/models/silver/defi/lp/fuzio/silver__lp_actions_fuzio.yml @@ -0,0 +1,79 @@ +version: 2 +models: + - name: silver__lp_actions_fuzio + description: Records of liquidity provider that occurred on the Fuzio platform + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - MSG_INDEX + columns: + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 1 + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - name: TX_SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + 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: MSG_INDEX + description: "{{ doc('msg_index') }}" + tests: + - not_null + - name: LIQUIDITY_PROVIDER_ADDRESS + description: "{{ doc('liquidity_provider_address') }}" + tests: + - not_null + - name: LP_ACTION + description: "{{ doc('lp_action') }}" + tests: + - not_null + - name: POOL_ADDRESS + description: "{{ doc('pool_address') }}" + tests: + - not_null + - name: POOL_NAME + description: "{{ doc('pool_name') }}" + tests: + - not_null + - name: TOKEN1_AMOUNT + description: "The amount of the first token provided by the liquidity provider" + tests: + - not_null + - name: TOKEN1_CURRENCY + description: "The currency of the first token provided by the liquidity provider" + tests: + - not_null + - name: TOKEN2_AMOUNT + description: "The amount of the second token provided by the liquidity provider" + tests: + - not_null + - name: TOKEN2_CURRENCY + description: "The currency of the second token provided by the liquidity provider" + tests: + - not_null + - name: LP_TOKEN_AMOUNT + description: "{{ doc('lp_token_amount') }}" + tests: + - not_null + - name: LP_TOKEN_ADDRESS + description: "{{ doc('lp_token_address') }}" + tests: + - not_null + diff --git a/models/silver/defi/lp/fuzio/silver__lp_staking_actions_fuzio.sql b/models/silver/defi/lp/fuzio/silver__lp_staking_actions_fuzio.sql new file mode 100644 index 0000000..56c6bbb --- /dev/null +++ b/models/silver/defi/lp/fuzio/silver__lp_staking_actions_fuzio.sql @@ -0,0 +1,160 @@ +{{ config( + materialized = 'incremental', + unique_key = ['tx_id','msg_index'], + incremental_strategy = 'merge', + cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ] +) }} + +WITH all_contacts AS ( + + SELECT + contract_address, + label + FROM + {{ ref('silver__contracts') }} +), +rel_contracts AS ( + SELECT + contract_address, + label AS pool_name + FROM + all_contacts + WHERE + label ILIKE 'Fuzio%' +), +contract_info AS ( + SELECT + contract_address, + DATA :lp_token_address :: STRING AS lp_token_address, + DATA :token1_denom :native :: STRING AS token1_currency, + DATA :token2_denom :native :: STRING AS token2_currency + FROM + {{ ref('silver__contract_info') }} +), +contract_config AS ( + SELECT + contract_address, + DATA :lp_token_contract :: STRING AS lp_token_address + FROM + {{ ref('silver__contract_config') }} +), +all_txns AS ( + SELECT + block_id, + block_timestamp, + tx_id, + tx_succeeded, + msg_group, + msg_sub_group, + msg_type, + msg_index, + attribute_key, + attribute_value, + _inserted_timestamp + FROM + {{ ref('silver__msg_attributes') }} A + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} + ) +{% endif %} +), +rel_txns AS ( + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + JOIN rel_contracts b + ON A.attribute_value = b.contract_address + WHERE + msg_type = 'execute' + AND attribute_key = '_contract_address' + INTERSECT + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + WHERE + msg_type = 'wasm' + AND attribute_key = 'action' + AND attribute_value IN ( + 'bond', + 'unbond' + ) +), +wasm AS ( + SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp, + OBJECT_AGG( + attribute_key :: STRING, + attribute_value :: variant + ) AS j, + j :_contract_address :: STRING AS contract_address, + j :action :: STRING AS action, + j :owner :: STRING AS owner, + j :amount :: INT AS amount + FROM + all_txns A + JOIN rel_txns 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 + msg_type = 'wasm' + GROUP BY + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp + HAVING + action IN ( + 'bond', + 'unbond' + ) +) +SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + A.owner AS liquidity_provider_address, + A.action AS lp_staking_action, + A.contract_address AS staking_pool_address, + b.pool_name AS staking_pool_name, + A.amount, + C.lp_token_address AS pool_address, + d.label AS pool_name, + A._inserted_timestamp +FROM + wasm A + JOIN rel_contracts b + ON A.contract_address = b.contract_address + JOIN contract_config C + ON A.contract_address = C.contract_address + JOIN all_contacts d + ON C.lp_token_address = d.contract_address diff --git a/models/silver/defi/lp/fuzio/silver__lp_staking_reward_actions_fuzio.sql b/models/silver/defi/lp/fuzio/silver__lp_staking_reward_actions_fuzio.sql new file mode 100644 index 0000000..55cbd15 --- /dev/null +++ b/models/silver/defi/lp/fuzio/silver__lp_staking_reward_actions_fuzio.sql @@ -0,0 +1,174 @@ +{{ config( + materialized = 'incremental', + unique_key = ['tx_id','msg_index'], + incremental_strategy = 'merge', + cluster_by = ['_inserted_timestamp::DATE', 'block_timestamp::DATE' ] +) }} + +WITH all_contacts AS ( + + SELECT + contract_address, + label + FROM + {{ ref('silver__contracts') }} +), +rel_contracts AS ( + SELECT + contract_address, + label AS pool_name + FROM + all_contacts + WHERE + label ILIKE 'Fuzio%' +), +contract_info AS ( + SELECT + contract_address, + DATA :lp_token_address :: STRING AS lp_token_address, + DATA :token1_denom :native :: STRING AS token1_currency, + DATA :token2_denom :native :: STRING AS token2_currency + FROM + {{ ref('silver__contract_info') }} +), +contract_config AS ( + SELECT + contract_address, + DATA :lp_token_contract :: STRING AS lp_token_address + FROM + {{ ref('silver__contract_config') }} +), +all_txns AS ( + SELECT + block_id, + block_timestamp, + tx_id, + tx_succeeded, + msg_group, + msg_sub_group, + msg_type, + msg_index, + attribute_key, + attribute_value, + _inserted_timestamp + FROM + {{ ref('silver__msg_attributes') }} A + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} + ) +{% endif %} +), +rel_txns AS ( + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + JOIN rel_contracts b + ON A.attribute_value = b.contract_address + WHERE + msg_type = 'execute' + AND attribute_key = '_contract_address' + INTERSECT + SELECT + tx_id, + block_timestamp, + msg_group, + msg_sub_group + FROM + all_txns A + WHERE + msg_type = 'wasm' + AND attribute_key = 'action' + AND attribute_value = 'withdraw' +), +wasmtran AS ( + SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp, + OBJECT_AGG( + attribute_key :: STRING, + attribute_value :: variant + ) AS j, + j :_contract_address :: STRING AS contract_address, + j :action :: STRING AS action, + j :owner :: STRING AS owner, + j :amount :: STRING AS amount, + j :sender :: STRING AS sender, + j :recipient :: STRING AS recipient + FROM + all_txns A + JOIN rel_txns 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 + msg_type IN( + 'wasm', + 'transfer' + ) + GROUP BY + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + _inserted_timestamp +) +SELECT + A.block_id, + A.block_timestamp, + A.tx_succeeded, + A.tx_id, + A.msg_group, + A.msg_sub_group, + A.msg_index, + A.owner AS liquidity_provider_address, + A.action AS lp_reward_action, + A.contract_address AS staking_pool_address, + b.pool_name AS staking_pool_name, + SPLIT_PART( + TRIM( + REGEXP_REPLACE( + a_tran.amount, + '[^[:digit:]]', + ' ' + ) + ), + ' ', + 0 + ) AS reward_amount, + RIGHT(a_tran.amount, LENGTH(a_tran.amount) - LENGTH(SPLIT_PART(TRIM(REGEXP_REPLACE(a_tran.amount, '[^[:digit:]]', ' ')), ' ', 0))) AS reward_currency, + C.lp_token_address AS pool_address, + d.label AS pool_name, + A._inserted_timestamp +FROM + wasmtran A + JOIN wasmtran a_tran + ON A.tx_id = a_tran.tx_id + AND A.msg_group = a_tran.msg_group + AND A.msg_sub_group = a_tran.msg_sub_group + AND A.owner = a_tran.recipient + AND A.contract_address = a_tran.sender + JOIN rel_contracts b + ON A.contract_address = b.contract_address + JOIN contract_config C + ON A.contract_address = C.contract_address + JOIN all_contacts d + ON C.lp_token_address = d.contract_address