diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_event_schema.yml b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_event_schema.yml index 36a4e868118..282257410ac 100644 --- a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_event_schema.yml +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_event_schema.yml @@ -2275,3 +2275,97 @@ models: description: The funding fee amount associated with the update. - name: is_long description: A boolean indicating if the position is a long position (`True` for long, `False` for short). + + - name: gmx_v2_arbitrum_swap_fees_collected + meta: + blockchain: arbitrum + sector: dex + project: gmx + contributors: ai_data_master, gmx-io + config: + tags: ['arbitrum', 'gmx', 'event', 'swap_fee'] + description: | + Processes decoded event data for `SwapFeesCollected` events on the GMX platform across the Arbitrum blockchain. + This model extracts key details such as fee amounts, trade keys, and fee types for analyzing swap fee collection behavior. + data_tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - tx_hash + - index + columns: + - *blockchain + - *block_time + - *block_date + - *block_number + - *tx_hash + - *index + - *contract_address + - name: tx_from + description: The address initiating the transaction. + - name: tx_to + description: The recipient address of the transaction. + - name: event_name + description: The name of the event emitted, always `SwapFeesCollected`. + - *msg_sender + - name: ui_fee_receiver + description: The address receiving the UI fee. + - name: market + description: The specific GMX market where the swap occurred. + - name: token + description: The token involved in the swap transaction. + - name: token_price + description: The price of the token at the time of the swap. + - name: fee_receiver_amount + description: The amount received by the fee receiver. + - name: fee_amount_for_pool + description: The amount of fees sent to the pool. + - name: amount_after_fees + description: The amount remaining after fees were deducted. + - name: ui_fee_receiver_factor + description: The factor used to calculate the UI fee. + - name: ui_fee_amount + description: The total UI fee amount deducted from the transaction. + - name: trade_key + description: A unique identifier for the trade. + - name: swap_fee_type + description: The type of fee associated with the swap. + - name: action_type + description: The action performed in the swap event (e.g., deposit, withdrawal, or swap). + + - name: gmx_v2_arbitrum_position_impact_pool_distributed + meta: + blockchain: arbitrum + sector: dex + project: gmx + contributors: ai_data_master, gmx-io + config: + tags: ['arbitrum', 'gmx', 'event', 'position_impact'] + description: | + Processes decoded event data for `PositionImpactPoolDistributed` events on the GMX platform across the Arbitrum blockchain. + This model extracts key details such as distribution amounts and pool impact metrics to analyze the effect of position impact distribution. + data_tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - tx_hash + - index + columns: + - *blockchain + - *block_time + - *block_date + - *block_number + - *tx_hash + - *index + - *contract_address + - name: tx_from + description: The address initiating the transaction. + - name: tx_to + description: The recipient address of the transaction. + - name: event_name + description: The name of the event emitted, always `PositionImpactPoolDistributed`. + - *msg_sender + - name: market + description: The specific GMX market where the position impact occurred. + - name: distribution_amount + description: The amount distributed to the impact pool. + - name: next_position_impact_pool_amount + description: The updated position impact pool amount after the event. diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_collected.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_collected.sql index 7ef09cf95a9..4beb4de3754 100644 --- a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_collected.sql +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_collected.sql @@ -302,9 +302,9 @@ WITH evt_data_1 AS ( collateral_token_price_min / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_min, collateral_token_price_max / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_max, trade_size_usd / POWER(10, 30) AS trade_size_usd, - funding_fee_amount / POWER(10, collateral_token_decimals + 15) AS funding_fee_amount, - claimable_long_token_amount / POWER(10, long_token_decimals + 15) AS claimable_long_token_amount, - claimable_short_token_amount / POWER(10, short_token_decimals + 15) AS claimable_short_token_amount, + funding_fee_amount / POWER(10, collateral_token_decimals) AS funding_fee_amount, + claimable_long_token_amount / POWER(10, long_token_decimals) AS claimable_long_token_amount, + claimable_short_token_amount / POWER(10, short_token_decimals) AS claimable_short_token_amount, latest_funding_fee_amount_per_size / POWER(10, collateral_token_decimals + 15) AS latest_funding_fee_amount_per_size, latest_long_token_claimable_funding_amount_per_size / POWER(10, long_token_decimals + 15) AS latest_long_token_claimable_funding_amount_per_size, latest_short_token_claimable_funding_amount_per_size / POWER(10, short_token_decimals + 15) AS latest_short_token_claimable_funding_amount_per_size, diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_info.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_info.sql index 355dc8b647d..f4cb92fae17 100644 --- a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_info.sql +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_fees_info.sql @@ -303,9 +303,9 @@ WITH evt_data_1 AS ( collateral_token_price_min / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_min, collateral_token_price_max / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_max, trade_size_usd / POWER(10, 30) AS trade_size_usd, - funding_fee_amount / POWER(10, collateral_token_decimals + 15) AS funding_fee_amount, - claimable_long_token_amount / POWER(10, long_token_decimals + 15) AS claimable_long_token_amount, - claimable_short_token_amount / POWER(10, short_token_decimals + 15) AS claimable_short_token_amount, + funding_fee_amount / POWER(10, collateral_token_decimals) AS funding_fee_amount, + claimable_long_token_amount / POWER(10, long_token_decimals) AS claimable_long_token_amount, + claimable_short_token_amount / POWER(10, short_token_decimals) AS claimable_short_token_amount, latest_funding_fee_amount_per_size / POWER(10, collateral_token_decimals + 15) AS latest_funding_fee_amount_per_size, latest_long_token_claimable_funding_amount_per_size / POWER(10, long_token_decimals + 15) AS latest_long_token_claimable_funding_amount_per_size, latest_short_token_claimable_funding_amount_per_size / POWER(10, short_token_decimals + 15) AS latest_short_token_claimable_funding_amount_per_size, diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_impact_pool_distributed.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_impact_pool_distributed.sql new file mode 100644 index 00000000000..960a35ad7e1 --- /dev/null +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_position_impact_pool_distributed.sql @@ -0,0 +1,174 @@ +{{ + config( + schema = 'gmx_v2_arbitrum', + alias = 'position_impact_pool_distributed', + materialized = 'incremental', + unique_key = ['tx_hash', 'index'], + incremental_strategy = 'merge' + ) +}} + +{%- set event_name = 'PositionImpactPoolDistributed' -%} +{%- set blockchain_name = 'arbitrum' -%} + +WITH evt_data_1 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog1')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +, evt_data_2 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog2')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +-- unite 2 tables +, evt_data AS ( + SELECT * + FROM evt_data_1 + UNION ALL + SELECT * + FROM evt_data_2 +) + +, parsed_data AS ( + SELECT + tx_hash, + index, + json_query(data, 'lax $.addressItems' OMIT QUOTES) AS address_items, + json_query(data, 'lax $.uintItems' OMIT QUOTES) AS uint_items + FROM + evt_data +) + +, address_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(address_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, uint_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(uint_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, combined AS ( + SELECT * + FROM address_items_parsed + UNION ALL + SELECT * + FROM uint_items_parsed +) + +, evt_data_parsed AS ( + SELECT + tx_hash, + index, + + MAX(CASE WHEN key_name = 'market' THEN value END) AS market, + MAX(CASE WHEN key_name = 'distributionAmount' THEN value END) AS distribution_amount, + MAX(CASE WHEN key_name = 'nextPositionImpactPoolAmount' THEN value END) AS next_position_impact_pool_amount + + FROM + combined + GROUP BY tx_hash, index +) + +, event_data AS ( + SELECT + blockchain, + block_time, + block_number, + ED.tx_hash, + ED.index, + contract_address, + event_name, + msg_sender, + + from_hex(market) AS market, + TRY_CAST(distribution_amount AS DOUBLE) AS distribution_amount, + TRY_CAST(next_position_impact_pool_amount AS DOUBLE) AS next_position_impact_pool_amount + + FROM evt_data AS ED + LEFT JOIN evt_data_parsed AS EDP + ON ED.tx_hash = EDP.tx_hash + AND ED.index = EDP.index +) + +, full_data AS ( + SELECT + ED.blockchain, + block_time, + DATE(block_time) AS block_date, + block_number, + tx_hash, + index, + ED.contract_address, + event_name, + msg_sender, + + ED.market, + CASE + WHEN distribution_amount = 0 THEN 0 + ELSE distribution_amount / POWER(10, MD.index_token_decimals) + END AS distribution_amount, + CASE + WHEN next_position_impact_pool_amount = 0 THEN 0 + ELSE next_position_impact_pool_amount / POWER(10, MD.index_token_decimals) + END AS next_position_impact_pool_amount + + FROM event_data AS ED + LEFT JOIN {{ ref('gmx_v2_arbitrum_markets_data') }} AS MD + ON ED.market = MD.market +) + +--can be removed once decoded tables are fully denormalized +{{ + add_tx_columns( + model_cte = 'full_data' + , blockchain = blockchain_name + , columns = ['from', 'to'] + ) +}} \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_swap_fees_collected.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_swap_fees_collected.sql new file mode 100644 index 00000000000..025534e9c9e --- /dev/null +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/arbitrum/gmx_v2_arbitrum_swap_fees_collected.sql @@ -0,0 +1,220 @@ +{{ + config( + schema = 'gmx_v2_arbitrum', + alias = 'swap_fees_collected', + materialized = 'incremental', + unique_key = ['tx_hash', 'index'], + incremental_strategy = 'merge' + ) +}} + +{%- set event_name = 'SwapFeesCollected' -%} +{%- set blockchain_name = 'arbitrum' -%} + +WITH evt_data_1 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog1')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +, evt_data_2 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_arbitrum','EventEmitter_evt_EventLog2')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +-- unite 2 tables +, evt_data AS ( + SELECT * + FROM evt_data_1 + UNION ALL + SELECT * + FROM evt_data_2 +) + +, parsed_data AS ( + SELECT + tx_hash, + index, + json_query(data, 'lax $.addressItems' OMIT QUOTES) AS address_items, + json_query(data, 'lax $.uintItems' OMIT QUOTES) AS uint_items, + json_query(data, 'lax $.bytes32Items' OMIT QUOTES) AS bytes32_items + FROM + evt_data +) + +, address_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(address_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, uint_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(uint_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, bytes32_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(bytes32_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, combined AS ( + SELECT * + FROM address_items_parsed + UNION ALL + SELECT * + FROM uint_items_parsed + UNION ALL + SELECT * + FROM bytes32_items_parsed +) + +, evt_data_parsed AS ( + SELECT + tx_hash, + index, + + MAX(CASE WHEN key_name = 'uiFeeReceiver' THEN value END) AS ui_fee_receiver, + MAX(CASE WHEN key_name = 'market' THEN value END) AS market, + MAX(CASE WHEN key_name = 'token' THEN value END) AS token, + + MAX(CASE WHEN key_name = 'tokenPrice' THEN value END) AS token_price, + MAX(CASE WHEN key_name = 'feeReceiverAmount' THEN value END) AS fee_receiver_amount, + MAX(CASE WHEN key_name = 'feeAmountForPool' THEN value END) AS fee_amount_for_pool, + MAX(CASE WHEN key_name = 'amountAfterFees' THEN value END) AS amount_after_fees, + MAX(CASE WHEN key_name = 'uiFeeReceiverFactor' THEN value END) AS ui_fee_receiver_factor, + MAX(CASE WHEN key_name = 'uiFeeAmount' THEN value END) AS ui_fee_amount, + + MAX(CASE WHEN key_name = 'tradeKey' THEN value END) AS trade_key, + MAX(CASE WHEN key_name = 'swapFeeType' THEN value END) AS swap_fee_type + + FROM + combined + GROUP BY tx_hash, index +) + +, event_data AS ( + SELECT + blockchain, + block_time, + block_number, + ED.tx_hash, + ED.index, + contract_address, + event_name, + msg_sender, + + from_hex(ui_fee_receiver) AS ui_fee_receiver, + from_hex(market) AS market, + from_hex(token) AS token, + + TRY_CAST(token_price AS DOUBLE) token_price, + TRY_CAST(fee_receiver_amount AS DOUBLE) fee_receiver_amount, + TRY_CAST(fee_amount_for_pool AS DOUBLE) fee_amount_for_pool, + TRY_CAST(amount_after_fees AS DOUBLE) amount_after_fees, + TRY_CAST(ui_fee_receiver_factor AS DOUBLE) ui_fee_receiver_factor, + TRY_CAST(ui_fee_amount AS DOUBLE) ui_fee_amount, + + from_hex(trade_key) AS trade_key, + from_hex(swap_fee_type) AS swap_fee_type + + FROM evt_data AS ED + LEFT JOIN evt_data_parsed AS EDP + ON ED.tx_hash = EDP.tx_hash + AND ED.index = EDP.index +) + +, full_data AS ( + SELECT + ED.blockchain, + block_time, + DATE(block_time) AS block_date, + block_number, + tx_hash, + index, + ED.contract_address, + event_name, + msg_sender, + + ui_fee_receiver, + market, + ED.token, + + token_price / POWER(10, 30 - ERC20.decimals) AS token_price, + fee_receiver_amount / POWER(10, ERC20.decimals) AS fee_receiver_amount, + fee_amount_for_pool / POWER(10, ERC20.decimals) AS fee_amount_for_pool, + amount_after_fees / POWER(10, ERC20.decimals) AS amount_after_fees, + ui_fee_receiver_factor / POWER(10, 30) AS ui_fee_receiver_factor, + ui_fee_amount / POWER(10, ERC20.decimals) AS ui_fee_amount, + + trade_key, + swap_fee_type, + CASE + WHEN swap_fee_type = 0x39226eb4fed85317aa310fa53f734c7af59274c49325ab568f9c4592250e8cc5 THEN 'deposit' + WHEN swap_fee_type = 0xda1ac8fcb4f900f8ab7c364d553e5b6b8bdc58f74160df840be80995056f3838 THEN 'withdrawal' + WHEN swap_fee_type = 0x7ad0b6f464d338ea140ff9ef891b4a69cf89f107060a105c31bb985d9e532214 THEN 'swap' + END AS action_type + + FROM event_data AS ED + LEFT JOIN {{ ref('gmx_v2_arbitrum_erc20') }} AS ERC20 + ON ED.token = ERC20.contract_address +) + +--can be removed once decoded tables are fully denormalized +{{ + add_tx_columns( + model_cte = 'full_data' + , blockchain = blockchain_name + , columns = ['from', 'to'] + ) +}} \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_event_schema.yml b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_event_schema.yml index f8c25f3763c..1e0c0276163 100644 --- a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_event_schema.yml +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_event_schema.yml @@ -2275,3 +2275,97 @@ models: description: The funding fee amount associated with the update. - name: is_long description: A boolean indicating if the position is a long position (`True` for long, `False` for short). + + - name: gmx_v2_avalanche_c_swap_fees_collected + meta: + blockchain: avalanche_c + sector: dex + project: gmx + contributors: ai_data_master, gmx-io + config: + tags: ['avalanche_c', 'gmx', 'event', 'swap_fee'] + description: | + Processes decoded event data for `SwapFeesCollected` events on the GMX platform across the Avalanche blockchain. + This model extracts key details such as fee amounts, trade keys, and fee types for analyzing swap fee collection behavior. + data_tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - tx_hash + - index + columns: + - *blockchain + - *block_time + - *block_date + - *block_number + - *tx_hash + - *index + - *contract_address + - name: tx_from + description: The address initiating the transaction. + - name: tx_to + description: The recipient address of the transaction. + - name: event_name + description: The name of the event emitted, always `SwapFeesCollected`. + - *msg_sender + - name: ui_fee_receiver + description: The address receiving the UI fee. + - name: market + description: The specific GMX market where the swap occurred. + - name: token + description: The token involved in the swap transaction. + - name: token_price + description: The price of the token at the time of the swap. + - name: fee_receiver_amount + description: The amount received by the fee receiver. + - name: fee_amount_for_pool + description: The amount of fees sent to the pool. + - name: amount_after_fees + description: The amount remaining after fees were deducted. + - name: ui_fee_receiver_factor + description: The factor used to calculate the UI fee. + - name: ui_fee_amount + description: The total UI fee amount deducted from the transaction. + - name: trade_key + description: A unique identifier for the trade. + - name: swap_fee_type + description: The type of fee associated with the swap. + - name: action_type + description: The action performed in the swap event (e.g., deposit, withdrawal, or swap). + + - name: gmx_v2_avalanche_c_position_impact_pool_distributed + meta: + blockchain: avalanche_c + sector: dex + project: gmx + contributors: ai_data_master, gmx-io + config: + tags: ['avalanche_c', 'gmx', 'event', 'position_impact'] + description: | + Processes decoded event data for `PositionImpactPoolDistributed` events on the GMX platform across the Avalanche blockchain. + This model extracts key details such as distribution amounts and pool impact metrics to analyze the effect of position impact distribution. + data_tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - tx_hash + - index + columns: + - *blockchain + - *block_time + - *block_date + - *block_number + - *tx_hash + - *index + - *contract_address + - name: tx_from + description: The address initiating the transaction. + - name: tx_to + description: The recipient address of the transaction. + - name: event_name + description: The name of the event emitted, always `PositionImpactPoolDistributed`. + - *msg_sender + - name: market + description: The specific GMX market where the position impact occurred. + - name: distribution_amount + description: The amount distributed to the impact pool. + - name: next_position_impact_pool_amount + description: The updated position impact pool amount after the event. diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_collected.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_collected.sql index d138becbf80..850b7d48214 100644 --- a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_collected.sql +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_collected.sql @@ -302,9 +302,9 @@ WITH evt_data_1 AS ( collateral_token_price_min / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_min, collateral_token_price_max / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_max, trade_size_usd / POWER(10, 30) AS trade_size_usd, - funding_fee_amount / POWER(10, collateral_token_decimals + 15) AS funding_fee_amount, - claimable_long_token_amount / POWER(10, long_token_decimals + 15) AS claimable_long_token_amount, - claimable_short_token_amount / POWER(10, short_token_decimals + 15) AS claimable_short_token_amount, + funding_fee_amount / POWER(10, collateral_token_decimals) AS funding_fee_amount, + claimable_long_token_amount / POWER(10, long_token_decimals) AS claimable_long_token_amount, + claimable_short_token_amount / POWER(10, short_token_decimals) AS claimable_short_token_amount, latest_funding_fee_amount_per_size / POWER(10, collateral_token_decimals + 15) AS latest_funding_fee_amount_per_size, latest_long_token_claimable_funding_amount_per_size / POWER(10, long_token_decimals + 15) AS latest_long_token_claimable_funding_amount_per_size, latest_short_token_claimable_funding_amount_per_size / POWER(10, short_token_decimals + 15) AS latest_short_token_claimable_funding_amount_per_size, diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_info.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_info.sql index 092bf293fdf..4acc7ff834c 100644 --- a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_info.sql +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_fees_info.sql @@ -303,9 +303,9 @@ WITH evt_data_1 AS ( collateral_token_price_min / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_min, collateral_token_price_max / POWER(10, 30 - collateral_token_decimals) AS collateral_token_price_max, trade_size_usd / POWER(10, 30) AS trade_size_usd, - funding_fee_amount / POWER(10, collateral_token_decimals + 15) AS funding_fee_amount, - claimable_long_token_amount / POWER(10, long_token_decimals + 15) AS claimable_long_token_amount, - claimable_short_token_amount / POWER(10, short_token_decimals + 15) AS claimable_short_token_amount, + funding_fee_amount / POWER(10, collateral_token_decimals) AS funding_fee_amount, + claimable_long_token_amount / POWER(10, long_token_decimals) AS claimable_long_token_amount, + claimable_short_token_amount / POWER(10, short_token_decimals) AS claimable_short_token_amount, latest_funding_fee_amount_per_size / POWER(10, collateral_token_decimals + 15) AS latest_funding_fee_amount_per_size, latest_long_token_claimable_funding_amount_per_size / POWER(10, long_token_decimals + 15) AS latest_long_token_claimable_funding_amount_per_size, latest_short_token_claimable_funding_amount_per_size / POWER(10, short_token_decimals + 15) AS latest_short_token_claimable_funding_amount_per_size, diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_impact_pool_distributed.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_impact_pool_distributed.sql new file mode 100644 index 00000000000..abcf3aa54da --- /dev/null +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_position_impact_pool_distributed.sql @@ -0,0 +1,174 @@ +{{ + config( + schema = 'gmx_v2_avalanche_c', + alias = 'position_impact_pool_distributed', + materialized = 'incremental', + unique_key = ['tx_hash', 'index'], + incremental_strategy = 'merge' + ) +}} + +{%- set event_name = 'PositionImpactPoolDistributed' -%} +{%- set blockchain_name = 'avalanche_c' -%} + +WITH evt_data_1 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_avalanche_c','EventEmitter_evt_EventLog1')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +, evt_data_2 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_avalanche_c','EventEmitter_evt_EventLog2')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +-- unite 2 tables +, evt_data AS ( + SELECT * + FROM evt_data_1 + UNION ALL + SELECT * + FROM evt_data_2 +) + +, parsed_data AS ( + SELECT + tx_hash, + index, + json_query(data, 'lax $.addressItems' OMIT QUOTES) AS address_items, + json_query(data, 'lax $.uintItems' OMIT QUOTES) AS uint_items + FROM + evt_data +) + +, address_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(address_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, uint_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(uint_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, combined AS ( + SELECT * + FROM address_items_parsed + UNION ALL + SELECT * + FROM uint_items_parsed +) + +, evt_data_parsed AS ( + SELECT + tx_hash, + index, + + MAX(CASE WHEN key_name = 'market' THEN value END) AS market, + MAX(CASE WHEN key_name = 'distributionAmount' THEN value END) AS distribution_amount, + MAX(CASE WHEN key_name = 'nextPositionImpactPoolAmount' THEN value END) AS next_position_impact_pool_amount + + FROM + combined + GROUP BY tx_hash, index +) + +, event_data AS ( + SELECT + blockchain, + block_time, + block_number, + ED.tx_hash, + ED.index, + contract_address, + event_name, + msg_sender, + + from_hex(market) AS market, + TRY_CAST(distribution_amount AS DOUBLE) AS distribution_amount, + TRY_CAST(next_position_impact_pool_amount AS DOUBLE) AS next_position_impact_pool_amount + + FROM evt_data AS ED + LEFT JOIN evt_data_parsed AS EDP + ON ED.tx_hash = EDP.tx_hash + AND ED.index = EDP.index +) + +, full_data AS ( + SELECT + ED.blockchain, + block_time, + DATE(block_time) AS block_date, + block_number, + tx_hash, + index, + ED.contract_address, + event_name, + msg_sender, + + ED.market, + CASE + WHEN distribution_amount = 0 THEN 0 + ELSE distribution_amount / POWER(10, MD.index_token_decimals) + END AS distribution_amount, + CASE + WHEN next_position_impact_pool_amount = 0 THEN 0 + ELSE next_position_impact_pool_amount / POWER(10, MD.index_token_decimals) + END AS next_position_impact_pool_amount + + FROM event_data AS ED + LEFT JOIN {{ ref('gmx_v2_avalanche_c_markets_data') }} AS MD + ON ED.market = MD.market +) + +--can be removed once decoded tables are fully denormalized +{{ + add_tx_columns( + model_cte = 'full_data' + , blockchain = blockchain_name + , columns = ['from', 'to'] + ) +}} \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_swap_fees_collected.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_swap_fees_collected.sql new file mode 100644 index 00000000000..047bbbd064b --- /dev/null +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/avalanche_c/gmx_v2_avalanche_c_swap_fees_collected.sql @@ -0,0 +1,220 @@ +{{ + config( + schema = 'gmx_v2_avalanche_c', + alias = 'swap_fees_collected', + materialized = 'incremental', + unique_key = ['tx_hash', 'index'], + incremental_strategy = 'merge' + ) +}} + +{%- set event_name = 'SwapFeesCollected' -%} +{%- set blockchain_name = 'avalanche_c' -%} + +WITH evt_data_1 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_avalanche_c','EventEmitter_evt_EventLog1')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +, evt_data_2 AS ( + SELECT + -- Main Variables + '{{ blockchain_name }}' AS blockchain, + evt_block_time AS block_time, + evt_block_number AS block_number, + evt_tx_hash AS tx_hash, + evt_index AS index, + contract_address, + eventName AS event_name, + eventData AS data, + msgSender AS msg_sender + FROM {{ source('gmx_v2_avalanche_c','EventEmitter_evt_EventLog2')}} + WHERE eventName = '{{ event_name }}' + {% if is_incremental() %} + AND {{ incremental_predicate('evt_block_time') }} + {% endif %} +) + +-- unite 2 tables +, evt_data AS ( + SELECT * + FROM evt_data_1 + UNION ALL + SELECT * + FROM evt_data_2 +) + +, parsed_data AS ( + SELECT + tx_hash, + index, + json_query(data, 'lax $.addressItems' OMIT QUOTES) AS address_items, + json_query(data, 'lax $.uintItems' OMIT QUOTES) AS uint_items, + json_query(data, 'lax $.bytes32Items' OMIT QUOTES) AS bytes32_items + FROM + evt_data +) + +, address_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(address_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, uint_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(uint_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, bytes32_items_parsed AS ( + SELECT + tx_hash, + index, + json_extract_scalar(CAST(item AS VARCHAR), '$.key') AS key_name, + json_extract_scalar(CAST(item AS VARCHAR), '$.value') AS value + FROM + parsed_data, + UNNEST( + CAST(json_extract(bytes32_items, '$.items') AS ARRAY(JSON)) + ) AS t(item) +) + +, combined AS ( + SELECT * + FROM address_items_parsed + UNION ALL + SELECT * + FROM uint_items_parsed + UNION ALL + SELECT * + FROM bytes32_items_parsed +) + +, evt_data_parsed AS ( + SELECT + tx_hash, + index, + + MAX(CASE WHEN key_name = 'uiFeeReceiver' THEN value END) AS ui_fee_receiver, + MAX(CASE WHEN key_name = 'market' THEN value END) AS market, + MAX(CASE WHEN key_name = 'token' THEN value END) AS token, + + MAX(CASE WHEN key_name = 'tokenPrice' THEN value END) AS token_price, + MAX(CASE WHEN key_name = 'feeReceiverAmount' THEN value END) AS fee_receiver_amount, + MAX(CASE WHEN key_name = 'feeAmountForPool' THEN value END) AS fee_amount_for_pool, + MAX(CASE WHEN key_name = 'amountAfterFees' THEN value END) AS amount_after_fees, + MAX(CASE WHEN key_name = 'uiFeeReceiverFactor' THEN value END) AS ui_fee_receiver_factor, + MAX(CASE WHEN key_name = 'uiFeeAmount' THEN value END) AS ui_fee_amount, + + MAX(CASE WHEN key_name = 'tradeKey' THEN value END) AS trade_key, + MAX(CASE WHEN key_name = 'swapFeeType' THEN value END) AS swap_fee_type + + FROM + combined + GROUP BY tx_hash, index +) + +, event_data AS ( + SELECT + blockchain, + block_time, + block_number, + ED.tx_hash, + ED.index, + contract_address, + event_name, + msg_sender, + + from_hex(ui_fee_receiver) AS ui_fee_receiver, + from_hex(market) AS market, + from_hex(token) AS token, + + TRY_CAST(token_price AS DOUBLE) token_price, + TRY_CAST(fee_receiver_amount AS DOUBLE) fee_receiver_amount, + TRY_CAST(fee_amount_for_pool AS DOUBLE) fee_amount_for_pool, + TRY_CAST(amount_after_fees AS DOUBLE) amount_after_fees, + TRY_CAST(ui_fee_receiver_factor AS DOUBLE) ui_fee_receiver_factor, + TRY_CAST(ui_fee_amount AS DOUBLE) ui_fee_amount, + + from_hex(trade_key) AS trade_key, + from_hex(swap_fee_type) AS swap_fee_type + + FROM evt_data AS ED + LEFT JOIN evt_data_parsed AS EDP + ON ED.tx_hash = EDP.tx_hash + AND ED.index = EDP.index +) + +, full_data AS ( + SELECT + ED.blockchain, + block_time, + DATE(block_time) AS block_date, + block_number, + tx_hash, + index, + ED.contract_address, + event_name, + msg_sender, + + ui_fee_receiver, + market, + ED.token, + + token_price / POWER(10, 30 - ERC20.decimals) AS token_price, + fee_receiver_amount / POWER(10, ERC20.decimals) AS fee_receiver_amount, + fee_amount_for_pool / POWER(10, ERC20.decimals) AS fee_amount_for_pool, + amount_after_fees / POWER(10, ERC20.decimals) AS amount_after_fees, + ui_fee_receiver_factor / POWER(10, 30) AS ui_fee_receiver_factor, + ui_fee_amount / POWER(10, ERC20.decimals) AS ui_fee_amount, + + trade_key, + swap_fee_type, + CASE + WHEN swap_fee_type = 0x39226eb4fed85317aa310fa53f734c7af59274c49325ab568f9c4592250e8cc5 THEN 'deposit' + WHEN swap_fee_type = 0xda1ac8fcb4f900f8ab7c364d553e5b6b8bdc58f74160df840be80995056f3838 THEN 'withdrawal' + WHEN swap_fee_type = 0x7ad0b6f464d338ea140ff9ef891b4a69cf89f107060a105c31bb985d9e532214 THEN 'swap' + END AS action_type + + FROM event_data AS ED + LEFT JOIN {{ ref('gmx_v2_avalanche_c_erc20') }} AS ERC20 + ON ED.token = ERC20.contract_address +) + +--can be removed once decoded tables are fully denormalized +{{ + add_tx_columns( + model_cte = 'full_data' + , blockchain = blockchain_name + , columns = ['from', 'to'] + ) +}} \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_event_schema.yml b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_event_schema.yml index f6783776688..bb3071fcdb7 100644 --- a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_event_schema.yml +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_event_schema.yml @@ -2141,3 +2141,89 @@ models: description: The funding fee amount associated with the update. - name: is_long description: A boolean indicating if the position is a long position (`True` for long, `False` for short). + + - name: gmx_v2_swap_fees_collected + meta: + blockchain: arbitrum, avalanche_c + sector: dex + project: gmx + contributors: ai_data_master, gmx-io + config: + tags: ['arbitrum', 'avalanche_c', 'gmx', 'event', 'swap_fee'] + description: | + Processes decoded event data for `SwapFeesCollected` events on the GMX platform across the Arbitrum and Avalanche blockchains. + This model extracts key details such as fee amounts, trade keys, and fee types for analyzing swap fee collection behavior. + + columns: + - *blockchain + - *block_time + - *block_date + - *block_number + - *tx_hash + - *index + - *contract_address + - name: tx_from + description: The address initiating the transaction. + - name: tx_to + description: The recipient address of the transaction. + - name: event_name + description: The name of the event emitted, always `SwapFeesCollected`. + - *msg_sender + - name: ui_fee_receiver + description: The address receiving the UI fee. + - name: market + description: The specific GMX market where the swap occurred. + - name: token + description: The token involved in the swap transaction. + - name: token_price + description: The price of the token at the time of the swap. + - name: fee_receiver_amount + description: The amount received by the fee receiver. + - name: fee_amount_for_pool + description: The amount of fees sent to the pool. + - name: amount_after_fees + description: The amount remaining after fees were deducted. + - name: ui_fee_receiver_factor + description: The factor used to calculate the UI fee. + - name: ui_fee_amount + description: The total UI fee amount deducted from the transaction. + - name: trade_key + description: A unique identifier for the trade. + - name: swap_fee_type + description: The type of fee associated with the swap. + - name: action_type + description: The action performed in the swap event (e.g., deposit, withdrawal, or swap). + + - name: gmx_v2_position_impact_pool_distributed + meta: + blockchain: arbitrum, avalanche_c + sector: dex + project: gmx + contributors: ai_data_master, gmx-io + config: + tags: ['arbitrum', 'avalanche_c', 'gmx', 'event', 'position_impact'] + description: | + Processes decoded event data for `PositionImpactPoolDistributed` events on the GMX platform across the Arbitrum and Avalanche blockchains. + This model extracts key details such as distribution amounts and pool impact metrics to analyze the effect of position impact distribution. + + columns: + - *blockchain + - *block_time + - *block_date + - *block_number + - *tx_hash + - *index + - *contract_address + - name: tx_from + description: The address initiating the transaction. + - name: tx_to + description: The recipient address of the transaction. + - name: event_name + description: The name of the event emitted, always `PositionImpactPoolDistributed`. + - *msg_sender + - name: market + description: The specific GMX market where the position impact occurred. + - name: distribution_amount + description: The amount distributed to the impact pool. + - name: next_position_impact_pool_amount + description: The updated position impact pool amount after the event. \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_position_impact_pool_distributed.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_position_impact_pool_distributed.sql new file mode 100644 index 00000000000..377bece5a54 --- /dev/null +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_position_impact_pool_distributed.sql @@ -0,0 +1,36 @@ +{{ config( + schema='gmx_v2', + alias = 'position_impact_pool_distributed', + post_hook='{{ expose_spells(blockchains = \'["arbitrum", "avalanche_c"]\', + spell_type = "project", + spell_name = "gmx", + contributors = \'["ai_data_master","gmx-io"]\') }}' + ) +}} + +{%- set chains = [ + 'arbitrum', + 'avalanche_c', +] -%} + +{%- for chain in chains -%} +SELECT + blockchain, + block_time, + block_date, + block_number, + tx_hash, + index, + contract_address, + tx_from, + tx_to, + event_name, + msg_sender, + market, + distribution_amount, + next_position_impact_pool_amount +FROM {{ ref('gmx_v2_' ~ chain ~ '_position_impact_pool_distributed') }} +{% if not loop.last %} +UNION ALL +{% endif %} +{%- endfor -%} \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_swap_fees_collected.sql b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_swap_fees_collected.sql new file mode 100644 index 00000000000..5d262d41967 --- /dev/null +++ b/dbt_subprojects/daily_spellbook/models/_projects/gmx/event/gmx_v2_swap_fees_collected.sql @@ -0,0 +1,45 @@ +{{ config( + schema='gmx_v2', + alias = 'swap_fees_collected', + post_hook='{{ expose_spells(blockchains = \'["arbitrum", "avalanche_c"]\', + spell_type = "project", + spell_name = "gmx", + contributors = \'["ai_data_master","gmx-io"]\') }}' + ) +}} + +{%- set chains = [ + 'arbitrum', + 'avalanche_c', +] -%} + +{%- for chain in chains -%} +SELECT + blockchain, + block_time, + block_date, + block_number, + tx_hash, + index, + contract_address, + tx_from, + tx_to, + event_name, + msg_sender, + ui_fee_receiver, + market, + token, + token_price, + fee_receiver_amount, + fee_amount_for_pool, + amount_after_fees, + ui_fee_receiver_factor, + ui_fee_amount, + trade_key, + swap_fee_type, + action_type +FROM {{ ref('gmx_v2_' ~ chain ~ '_swap_fees_collected') }} +{% if not loop.last %} +UNION ALL +{% endif %} +{%- endfor -%} \ No newline at end of file