diff --git a/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_liquidations.sql b/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_liquidations.sql index d4e0fef..c949596 100644 --- a/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_liquidations.sql +++ b/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_liquidations.sql @@ -66,12 +66,21 @@ parse_event_data AS ( event_data [0] [0] [2] [1] :: STRING AS collateral_token, TRY_TO_NUMBER( event_data [1] [0] [0] [1] :: STRING + ) / pow( + 10, + 30 ) AS size_in_usd, TRY_TO_NUMBER( event_data [1] [0] [1] [1] :: STRING + ) / pow( + 10, + 30 ) AS size_in_tokens, TRY_TO_NUMBER( event_data [1] [0] [2] [1] :: STRING + ) / pow( + 10, + 30 ) AS collateral_amount, TRY_TO_NUMBER( event_data [1] [0] [3] [1] :: STRING @@ -119,10 +128,10 @@ parse_event_data AS ( event_data [2] [0] [0] [1] :: STRING ) AS price_impact_usd, TRY_TO_NUMBER( - event_data [2] [0] [1] [1] :: STRING + event_data [1] [0] [12] [1] :: STRING ) AS base_pnl_usd, TRY_TO_NUMBER( - event_data [2] [0] [2] [1] :: STRING + event_data [1] [0] [13] [1] :: STRING ) AS uncapped_base_pnl_usd, event_data [3] [0] [0] [1] :: BOOLEAN AS is_long, event_data [4] [0] [0] [1] :: STRING AS order_key, @@ -166,46 +175,46 @@ SELECT collateral_token, C.token_symbol AS collateral_token_symbol, borrowing_factor AS borrowing_factor_unadj, - borrowing_factor :: FLOAT / pow( + borrowing_factor / pow( 10, 30 ) AS borrowing_factor, funding_fee_amount_per_size, execution_price AS execution_price_unadj, - execution_price :: FLOAT / pow(10, (30 - decimals)) AS execution_price, + execution_price / pow(10, (30 - decimals)) AS execution_price, size_delta_usd AS size_delta_usd_unadj, - size_delta_usd :: FLOAT / pow( + size_delta_usd / pow( 10, 30 ) AS size_delta_usd, size_delta_amount AS size_delta_amount_unadj, - size_delta_amount :: FLOAT / pow( + size_delta_amount / pow( 10, p.decimals ) AS size_delta_amount, collateral_delta_amount AS collateral_delta_amount_unadj, - collateral_delta_amount :: INT / pow( + collateral_delta_amount / pow( 10, C.token_decimals ) AS collateral_delta_amount, price_impact_diff_usd AS price_impact_diff_usd_unadj, - price_impact_diff_usd :: FLOAT / pow( + price_impact_diff_usd / pow( 10, 30 ) AS price_impact_diff_usd, order_type, price_impact_usd AS price_impact_usd_unadj, - price_impact_usd :: FLOAT / pow( + price_impact_usd / pow( 10, 30 ) AS price_impact_usd, base_pnl_usd AS base_pnl_usd_unadj, - base_pnl_usd :: FLOAT / pow( + base_pnl_usd / pow( 10, 30 ) AS base_pnl_usd, uncapped_base_pnl_usd AS uncapped_base_pnl_usd_unadj, - uncapped_base_pnl_usd :: FLOAT / pow( + uncapped_base_pnl_usd / pow( 10, 30 ) AS uncapped_base_pnl_usd, diff --git a/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_perps.sql b/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_perps.sql index 3a8835f..39a47b3 100644 --- a/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_perps.sql +++ b/models/silver/defi/derivatives/gmx/v2/silver_perps__gmxv2_perps.sql @@ -76,11 +76,21 @@ parse_data AS ( event_data [0] [0] [5] [1] :: STRING AS initial_collateral_token, event_data [1] [0] [0] [1] :: INT AS order_type, event_data [1] [0] [1] [1] AS decrease_position_swap_type, - event_data [1] [0] [2] [1] AS size_delta_usd, - event_data [1] [0] [3] [1] AS initial_collateral_delta_amount, - event_data [1] [0] [4] [1] AS trigger_price, - event_data [1] [0] [5] [1] AS acceptable_price, - event_data [1] [0] [6] [1] AS execution_fee, + TRY_TO_NUMBER( + event_data [1] [0] [2] [1] :: STRING + ) AS size_delta_usd, + TRY_TO_NUMBER( + event_data [1] [0] [3] [1] :: STRING + ) AS initial_collateral_delta_amount, + TRY_TO_NUMBER( + event_data [1] [0] [4] [1] :: STRING + ) AS trigger_price, + TRY_TO_NUMBER( + event_data [1] [0] [5] [1] :: STRING + ) AS acceptable_price, + TRY_TO_NUMBER( + event_data [1] [0] [6] [1] :: STRING + ) AS execution_fee, event_data [1] [0] [9] [1] :: INT AS updated_at_block, event_data [3] [0] [0] [1] AS is_long, event_data [3] [0] [1] [1] AS should_unwrap_native_token, @@ -154,21 +164,21 @@ SELECT END AS order_execution, decrease_position_swap_type :: INT AS market_reduce_flag, size_delta_usd AS size_delta_usd_unadj, - size_delta_usd :: FLOAT / pow( + size_delta_usd / pow( 10, 30 ) AS size_delta_usd, initial_collateral_delta_amount AS initial_collateral_delta_amount_unadj, - initial_collateral_delta_amount :: FLOAT / pow( + initial_collateral_delta_amount / pow( 10, C.token_decimals ) AS initial_collateral_delta_amount, trigger_price AS trigger_price_unadj, - trigger_price :: FLOAT / pow(10, (30 - decimals)) AS trigger_price, + trigger_price / pow(10, (30 - decimals)) AS trigger_price, acceptable_price AS acceptable_price_unadj, - acceptable_price :: FLOAT / pow(10, (30 - decimals)) AS acceptable_price, + acceptable_price / pow(10, (30 - decimals)) AS acceptable_price, execution_fee AS execution_fee_unadj, - execution_fee :: FLOAT / pow( + execution_fee / pow( 10, 18 ) AS execution_fee, @@ -217,7 +227,6 @@ SELECT order_type_raw, order_type, 'executed' AS order_execution, - -- We know these are now executed market_reduce_flag, size_delta_usd_unadj, size_delta_usd, diff --git a/models/silver/defi/derivatives/silver_perps__complete_perp_liquidations.sql b/models/silver/defi/derivatives/silver_perps__complete_perp_liquidations.sql index 76d8fa8..4117c2b 100644 --- a/models/silver/defi/derivatives/silver_perps__complete_perp_liquidations.sql +++ b/models/silver/defi/derivatives/silver_perps__complete_perp_liquidations.sql @@ -18,7 +18,6 @@ WITH vertex AS ( origin_function_signature, origin_from_address, origin_to_address, - -- market_type (always decrease only?) trader, digest AS liquidator, CASE @@ -62,7 +61,6 @@ gmx_v2 AS ( origin_function_signature, origin_from_address, origin_to_address, - -- market_type (always decrease only?) account AS trader, origin_from_address AS liquidator, -- GMX LiquidationHandler @@ -121,9 +119,7 @@ symmio AS ( price AS price_amount, liquidated_amount_unadj, liquidated_amount, - -- token quantity liquidated_amount_usd, - -- in usd value _log_id, modified_timestamp AS _inserted_timestamp FROM diff --git a/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.sql b/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.sql index 3a2a5de..bf7e38a 100644 --- a/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.sql +++ b/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.sql @@ -1,7 +1,7 @@ {{ config( materialized = 'incremental', incremental_strategy = 'delete+insert', - unique_key = '_log_id', + unique_key = 'product_id', cluster_by = ['block_timestamp::DATE'], tags = ['curated','reorg'] ) }} diff --git a/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.yml b/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.yml index cd819c8..c90d5ea 100644 --- a/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.yml +++ b/models/silver/defi/derivatives/symmio/silver_perps__symmio_dim_products.yml @@ -4,7 +4,7 @@ models: tests: - dbt_utils.unique_combination_of_columns: combination_of_columns: - - _log_id + - product_id columns: - name: BLOCK_NUMBER tests: @@ -132,7 +132,6 @@ models: min_value: 0 max_value: 1 - - name: PEAR_PRODUCTS_ID + - name: SYMMIO_PRODUCTS_ID tests: - - not_null - - unique \ No newline at end of file + - not_null \ No newline at end of file diff --git a/models/silver/defi/derivatives/symmio/silver_perps__symmio_liquidations.sql b/models/silver/defi/derivatives/symmio/silver_perps__symmio_liquidations.sql index b8401cc..f18b29b 100644 --- a/models/silver/defi/derivatives/symmio/silver_perps__symmio_liquidations.sql +++ b/models/silver/defi/derivatives/symmio/silver_perps__symmio_liquidations.sql @@ -78,9 +78,9 @@ sort_liquidate AS ( event_index, decoded_log :partyA :: STRING AS partyA, decoded_log :liquidationId :: STRING AS liquidationid, - f1.value :: INT AS closeId, - f2.value :: INT AS quoteId, - f3.value :: INT AS liquidatedAmount_unadj, + TRY_TO_NUMBER(f1.value::STRING) AS closeId, + TRY_TO_NUMBER(f2.value::STRING) AS quoteId, + TRY_TO_NUMBER(f3.value::STRING) AS liquidatedAmount_unadj, -- in token quantity liquidatedAmount_unadj * pow( 10, @@ -114,7 +114,7 @@ sort_liquidate AS ( {% if is_incremental() %} AND modified_timestamp >= ( SELECT - MAX(modified_timestamp) - INTERVAL '12 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -129,8 +129,8 @@ setsymbolprice AS ( decoded_log :liquidator :: STRING AS liquidator, decoded_log :partyA :: STRING AS partyA, decoded_log :liquidationId :: STRING AS liquidationid, - f1.value :: INT AS symbolId, - f2.value :: INT * pow( + TRY_TO_NUMBER(f1.value::STRING) AS symbolId, + TRY_TO_NUMBER(f2.value::STRING) * pow( 10, -18 ) AS price, @@ -152,7 +152,7 @@ setsymbolprice AS ( {% if is_incremental() %} AND modified_timestamp >= ( SELECT - MAX(modified_timestamp) - INTERVAL '12 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) @@ -186,7 +186,7 @@ combine AS ( q.symbolId, liquidatedAmount * price AS liquidatedAmount_usd, _log_id, - --modified_timestamp + _inserted_timestamp FROM sort_liquidate l LEFT JOIN sendquote q USING(quoteId) @@ -222,7 +222,7 @@ SELECT symbolId AS symbol_id, liquidatedAmount_usd AS liquidated_amount_usd, C._log_id, - --C.modified_timestamp, + C._inserted_timestamp, {{ dbt_utils.generate_surrogate_key( ['C.tx_hash','C.event_index'] ) }} AS symmio_liquidation_id, @@ -234,4 +234,4 @@ FROM LEFT JOIN {{ ref('silver_perps__symmio_dim_products') }} ON product_id = symbol_id qualify(ROW_NUMBER() over(PARTITION BY C._log_id ORDER BY - modified_timestamp DESC)) = 1 + C._inserted_timestamp DESC)) = 1 diff --git a/models/silver/defi/derivatives/symmio/silver_perps__symmio_perps.sql b/models/silver/defi/derivatives/symmio/silver_perps__symmio_perps.sql index 8782749..08a2c02 100644 --- a/models/silver/defi/derivatives/symmio/silver_perps__symmio_perps.sql +++ b/models/silver/defi/derivatives/symmio/silver_perps__symmio_perps.sql @@ -1,12 +1,13 @@ {{ config( materialized = 'incremental', incremental_strategy = 'delete+insert', - unique_key = ['tx_hash', 'quote_id'], + unique_key = ['_log_id', 'quote_id'], cluster_by = ['block_timestamp::DATE'], tags = ['curated','reorg'] ) }} -with symmio_events as ( +WITH symmio_events AS ( + SELECT tx_hash, block_number, @@ -24,30 +25,33 @@ with symmio_events as ( '-', event_index ) AS _log_id, - modified_timestamp as _inserted_timestamp, + modified_timestamp AS _inserted_timestamp, ez_decoded_event_logs_id FROM {{ ref('core__ez_decoded_event_logs') }} WHERE contract_address = LOWER('0x8f06459f184553e5d04f07f868720bdacab39395') AND topic_0 IN ( - '0x8a17f103c77224ce4d9bab74dad3bd002cd24cf88d2e191e86d18272c8f135dd', -- SendQuote - '0xa50f98254710514f60327a4e909cd0be099a62f316299907ef997f3dc4d1cda5', -- OpenPosition - '0x7f9710cf0d5a0ad968b7fc45b62e78bf71c0ca8ebb71a16128fc27b07fa5608d', -- RequestToClosePosition - '0xfa7483d69b899cf16df47cc736ab853f88135f704980d7d358a9746aead7a321' -- FillCloseRequest + '0x8a17f103c77224ce4d9bab74dad3bd002cd24cf88d2e191e86d18272c8f135dd', + -- SendQuote + '0xa50f98254710514f60327a4e909cd0be099a62f316299907ef997f3dc4d1cda5', + -- OpenPosition + '0x7f9710cf0d5a0ad968b7fc45b62e78bf71c0ca8ebb71a16128fc27b07fa5608d', + -- RequestToClosePosition + '0xfa7483d69b899cf16df47cc736ab853f88135f704980d7d358a9746aead7a321' -- FillCloseRequest ) - {% if is_incremental() %} - AND _inserted_timestamp >= ( - SELECT - MAX(_inserted_timestamp) - INTERVAL '12 hours' - FROM - {{ this }} - ) - AND _inserted_timestamp >= SYSDATE() - INTERVAL '7 day' - {% endif %} -), -send_quotes as ( +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '12 hours' + FROM + {{ this }} +) +AND _inserted_timestamp >= SYSDATE() - INTERVAL '7 day' +{% endif %} +), +send_quotes AS ( SELECT tx_hash, block_number, @@ -60,21 +64,21 @@ send_quotes as ( origin_function_signature, decoded_log, topic_0, - decoded_log:cva::decimal(38,0)/1e18 as cva, - TO_TIMESTAMP_NTZ(decoded_log:deadline::integer) as deadline, - decoded_log:lf::decimal(38,0)/1e18 as lf, - decoded_log:marketPrice::decimal(38,0)/1e18 as market_price, + TRY_TO_NUMBER(decoded_log:cva::STRING) / pow(10, 18) AS cva, + TO_TIMESTAMP_NTZ(decoded_log:deadline::integer) AS deadline, + TRY_TO_NUMBER(decoded_log:lf::STRING) / pow(10, 18) AS lf, + TRY_TO_NUMBER(decoded_log:marketPrice::STRING) / pow(10, 18) AS market_price, decoded_log:orderType::integer as order_type, decoded_log:partyA::string as party_a, - decoded_log:partyAmm::decimal(38,0)/1e18 as party_amm, - decoded_log:partyBmm::decimal(38,0)/1e18 as party_bmm, + TRY_TO_NUMBER(decoded_log:partyAmm::STRING) / pow(10, 18) as party_amm, + TRY_TO_NUMBER(decoded_log:partyBmm::STRING) / pow(10, 18) as party_bmm, decoded_log:partyBsWhiteList as party_bs_white_list, decoded_log:positionType::integer as position_type, - decoded_log:price::decimal(38,0)/1e18 as price, - decoded_log:quantity::decimal(38,0)/1e18 as quantity, + TRY_TO_NUMBER(decoded_log:price::STRING) / pow(10, 18) as price, + TRY_TO_NUMBER(decoded_log:quantity::STRING) / pow(10, 18) as quantity, decoded_log:quoteId::string as quote_id, decoded_log:symbolId::integer as symbol_id, - decoded_log:tradingFee::decimal(38,0)/1e18 as trading_fee, + TRY_TO_NUMBER(decoded_log:tradingFee::STRING) / pow(10, 18) as trading_fee, _log_id, _inserted_timestamp, ez_decoded_event_logs_id @@ -83,9 +87,8 @@ send_quotes as ( WHERE topic_0 = '0x8a17f103c77224ce4d9bab74dad3bd002cd24cf88d2e191e86d18272c8f135dd' ), - -open_positions as ( - select +open_positions AS ( + SELECT tx_hash, block_number, block_timestamp, @@ -97,11 +100,11 @@ open_positions as ( origin_function_signature, decoded_log, topic_0, - decoded_log:filledAmount::decimal(38,0)/1e18 as filled_amount, - decoded_log:openedPrice::decimal(38,0)/1e18 as opened_price, - decoded_log:partyA::string as party_a, - decoded_log:partyB::string as party_b, - decoded_log:quoteId::string as quote_id, + TRY_TO_NUMBER(decoded_log:filledAmount::STRING) / pow(10, 18) AS filled_amount, + TRY_TO_NUMBER(decoded_log:openedPrice::STRING) / pow(10, 18) AS opened_price, + decoded_log :partyA :: STRING AS party_a, + decoded_log :partyB :: STRING AS party_b, + decoded_log :quoteId :: STRING AS quote_id, _log_id, _inserted_timestamp, ez_decoded_event_logs_id @@ -110,9 +113,8 @@ open_positions as ( WHERE topic_0 = '0xa50f98254710514f60327a4e909cd0be099a62f316299907ef997f3dc4d1cda5' ), - -quote_status as ( - select +quote_status AS ( + SELECT l.tx_hash, l.block_number, l.block_timestamp, @@ -124,11 +126,11 @@ quote_status as ( l.origin_function_signature, l.decoded_log, l.topic_0, - l.symbol_id as product_id, - CASE - WHEN o.filled_amount is not null THEN 'filled' - ELSE 'unfilled' - END as status, + l.symbol_id AS product_id, + CASE + WHEN o.filled_amount IS NOT NULL THEN 'filled' + ELSE 'unfilled' + END AS status, l.cva, l.deadline, l.lf, @@ -151,59 +153,61 @@ quote_status as ( l.ez_decoded_event_logs_id FROM send_quotes l - LEFT JOIN {{ ref('silver_perps__symmio_dim_products') }} p + LEFT JOIN {{ ref('silver_perps__symmio_dim_products') }} + p ON l.symbol_id = p.product_id - LEFT JOIN open_positions o + LEFT JOIN open_positions o ON l.quote_id = o.quote_id - {% if is_incremental() %} - UNION ALL - select - l.tx_hash, - l.block_number, - l.block_timestamp, - l.origin_from_address, - l.origin_to_address, - l.contract_address, - l.event_name, - l.event_index, - l.origin_function_signature, - l.decoded_log, - l.topic_0, - l.product_id, - CASE - WHEN o.filled_amount is not null THEN 'filled' - ELSE 'unfilled' - END as status, - l.cva, - l.deadline, - l.lf, - l.market_price, - l.order_type, - l.party_a, - l.party_amm, - l.party_bmm, - l.party_bs_white_list, - l.position_type, - l.price, - l.quantity, - o.filled_amount, - o.opened_price, - l.quote_id, - l.trading_fee, - l.product_name, - l._inserted_timestamp, - l.ez_decoded_event_logs_id - FROM - {{this}} l - LEFT JOIN open_positions o - ON l.quote_id = o.quote_id - WHERE - l.status = 'unfilled' - and l.event_name ='SendQuote' - {% endif %} -), -request_close_position as ( +{% if is_incremental() %} +UNION ALL +SELECT + l.tx_hash, + l.block_number, + l.block_timestamp, + l.origin_from_address, + l.origin_to_address, + l.contract_address, + l.event_name, + l.event_index, + l.origin_function_signature, + l.decoded_log, + l.topic_0, + l.product_id, + CASE + WHEN o.filled_amount IS NOT NULL THEN 'filled' + ELSE 'unfilled' + END AS status, + l.cva, + l.deadline, + l.lf, + l.market_price, + l.order_type, + l.party_a, + l.party_amm, + l.party_bmm, + l.party_bs_white_list, + l.position_type, + l.price, + l.quantity, + o.filled_amount, + o.opened_price, + l.quote_id, + l.trading_fee, + l.product_name, + l._inserted_timestamp, + l.ez_decoded_event_logs_id +FROM + {{ this }} + l + LEFT JOIN open_positions o + ON l.quote_id = o.quote_id +WHERE + l.status = 'unfilled' + AND l.event_name = 'SendQuote' +{% endif %} +), +request_close_position AS ( SELECT tx_hash, block_number, @@ -216,15 +220,17 @@ request_close_position as ( origin_function_signature, decoded_log, topic_0, - decoded_log:closeId::integer as close_id, - decoded_log:closePrice::decimal(38,0)/1e18 as close_price, - TO_TIMESTAMP_NTZ(decoded_log:deadline::integer) as deadline, - decoded_log:orderType::integer as order_type, - decoded_log:partyA::string as party_a, - decoded_log:partyB::string as party_b, - decoded_log:quantityToClose::decimal(38,0)/1e18 as quantity_to_close, - decoded_log:quoteId::integer as quote_id, - decoded_log:quoteStatus::integer as quote_status, + decoded_log :closeId :: INTEGER AS close_id, + TRY_TO_NUMBER(decoded_log:closePrice::STRING) / pow(10, 18) AS close_price, + TO_TIMESTAMP_NTZ( + decoded_log :deadline :: INTEGER + ) AS deadline, + decoded_log :orderType :: INTEGER AS order_type, + decoded_log :partyA :: STRING AS party_a, + decoded_log :partyB :: STRING AS party_b, + TRY_TO_NUMBER(decoded_log:quantityToClose::STRING) / pow(10, 18) AS quantity_to_close, + decoded_log :quoteId :: INTEGER AS quote_id, + decoded_log :quoteStatus :: INTEGER AS quote_status, _log_id, _inserted_timestamp, ez_decoded_event_logs_id @@ -233,8 +239,7 @@ request_close_position as ( WHERE topic_0 = '0x7f9710cf0d5a0ad968b7fc45b62e78bf71c0ca8ebb71a16128fc27b07fa5608d' -- RequestToClosePosition ), - -fill_close_position as ( +fill_close_position AS ( SELECT tx_hash, block_number, @@ -247,13 +252,13 @@ fill_close_position as ( origin_function_signature, decoded_log, topic_0, - decoded_log:closeId::integer as close_id, - decoded_log:closedPrice::decimal(38,0)/1e18 as closed_price, - decoded_log:filledAmount::decimal(38,0)/1e18 as filled_amount, - decoded_log:partyA::string as party_a, - decoded_log:partyB::string as party_b, - decoded_log:quoteId::integer as quote_id, - decoded_log:quoteStatus::integer as quote_status, + decoded_log :closeId :: INTEGER AS close_id, + TRY_TO_NUMBER(decoded_log:closedPrice::STRING) / pow(10, 18) AS closed_price, + TRY_TO_NUMBER(decoded_log:filledAmount::STRING) / pow(10, 18) AS filled_amount, + decoded_log :partyA :: STRING AS party_a, + decoded_log :partyB :: STRING AS party_b, + decoded_log :quoteId :: INTEGER AS quote_id, + decoded_log :quoteStatus :: INTEGER AS quote_status, _log_id, _inserted_timestamp, ez_decoded_event_logs_id @@ -262,25 +267,57 @@ fill_close_position as ( WHERE topic_0 = '0xfa7483d69b899cf16df47cc736ab853f88135f704980d7d358a9746aead7a321' -- FillCloseRequest ), - -close_status as ( - select - coalesce(f.tx_hash, r.tx_hash) as tx_hash, - coalesce(f.block_number, r.block_number) as block_number, - coalesce(f.block_timestamp, r.block_timestamp) as block_timestamp, - coalesce(f.origin_from_address, r.origin_from_address) as origin_from_address, - coalesce(f.origin_to_address, r.origin_to_address) as origin_to_address, - coalesce(f.contract_address, r.contract_address) as contract_address, - coalesce(f.event_name, r.event_name) as event_name, - coalesce(f.event_index, r.event_index) as event_index, - coalesce(f.origin_function_signature, r.origin_function_signature) as origin_function_signature, - coalesce(f.decoded_log, r.decoded_log) as decoded_log, - coalesce(f.topic_0, r.topic_0) as topic_0, - q.product_id as product_id, - CASE - WHEN f.filled_amount is not null THEN 'filled' - ELSE 'unfilled' - END as status, +close_status AS ( + SELECT + COALESCE( + f.tx_hash, + r.tx_hash + ) AS tx_hash, + COALESCE( + f.block_number, + r.block_number + ) AS block_number, + COALESCE( + f.block_timestamp, + r.block_timestamp + ) AS block_timestamp, + COALESCE( + f.origin_from_address, + r.origin_from_address + ) AS origin_from_address, + COALESCE( + f.origin_to_address, + r.origin_to_address + ) AS origin_to_address, + COALESCE( + f.contract_address, + r.contract_address + ) AS contract_address, + COALESCE( + f.event_name, + r.event_name + ) AS event_name, + COALESCE( + f.event_index, + r.event_index + ) AS event_index, + COALESCE( + f.origin_function_signature, + r.origin_function_signature + ) AS origin_function_signature, + COALESCE( + f.decoded_log, + r.decoded_log + ) AS decoded_log, + COALESCE( + f.topic_0, + r.topic_0 + ) AS topic_0, + q.product_id AS product_id, + CASE + WHEN f.filled_amount IS NOT NULL THEN 'filled' + ELSE 'unfilled' + END AS status, q.cva, r.deadline, q.lf, @@ -291,117 +328,73 @@ close_status as ( q.party_bmm, q.party_bs_white_list, q.position_type, - f.closed_price as price, - r.quantity_to_close as quantity, + f.closed_price AS price, + r.quantity_to_close AS quantity, f.filled_amount, f.closed_price, r.quote_id, q.trading_fee, - q.product_name as product_name, + q.product_name AS product_name, r._log_id, r._inserted_timestamp, r.ez_decoded_event_logs_id FROM request_close_position r - LEFT JOIN quote_status q + LEFT JOIN quote_status q ON r.quote_id = q.quote_id - LEFT JOIN fill_close_position f + LEFT JOIN fill_close_position f ON r.quote_id = f.quote_id AND r.close_id = f.close_id - {% if is_incremental() %} - UNION ALL - select - l.tx_hash, - l.block_number, - l.block_timestamp, - l.origin_from_address, - l.origin_to_address, - l.contract_address, - l.event_name, - l.event_index, - l.origin_function_signature, - l.decoded_log, - l.topic_0, - l.product_id, - CASE - WHEN f.filled_amount is not null THEN 'filled' - ELSE 'unfilled' - END as status, - l.cva, - l.deadline, - l.lf, - l.market_price, - l.order_type, - l.party_a, - l.party_amm, - l.party_bmm, - l.party_bs_white_list, - l.position_type, - l.price, - l.quantity, - f.filled_amount, - f.closed_price, - l.quote_id, - l.trading_fee, - l.product_name, - l._log_id, - l._inserted_timestamp, - l.ez_decoded_event_logs_id - FROM - {{this}} l - LEFT JOIN fill_close_position f - ON l.quote_id = f.quote_id - WHERE - l.status = 'unfilled' - {% endif %} -) - -SELECT - tx_hash, - block_number, - block_timestamp, - origin_from_address, - origin_to_address, - contract_address, - event_name, - event_index, - origin_function_signature, - decoded_log, - topic_0, - product_id, - status, - cva, - deadline, - lf, - market_price, - order_type, - party_a, - party_amm, - party_bmm, - party_bs_white_list, - position_type, - 'open' as action_type, - price, - quantity, - filled_amount, - quote_id, - trading_fee, - product_name, - _log_id, - _inserted_timestamp, - ez_decoded_event_logs_id, - {{ dbt_utils.generate_surrogate_key( - ['tx_hash', 'quote_id'] - ) }} AS symmio_perps_id, - SYSDATE() AS inserted_timestamp, - SYSDATE() AS modified_timestamp, - '{{ invocation_id }}' AS _invocation_id -FROM - quote_status +{% if is_incremental() %} UNION ALL - -SELECT +SELECT + l.tx_hash, + l.block_number, + l.block_timestamp, + l.origin_from_address, + l.origin_to_address, + l.contract_address, + l.event_name, + l.event_index, + l.origin_function_signature, + l.decoded_log, + l.topic_0, + l.product_id, + CASE + WHEN f.filled_amount IS NOT NULL THEN 'filled' + ELSE 'unfilled' + END AS status, + l.cva, + l.deadline, + l.lf, + l.market_price, + l.order_type, + l.party_a, + l.party_amm, + l.party_bmm, + l.party_bs_white_list, + l.position_type, + l.price, + l.quantity, + f.filled_amount, + f.closed_price, + l.quote_id, + l.trading_fee, + l.product_name, + l._log_id, + l._inserted_timestamp, + l.ez_decoded_event_logs_id +FROM + {{ this }} + l + LEFT JOIN fill_close_position f + ON l.quote_id = f.quote_id +WHERE + l.status = 'unfilled' +{% endif %} +) +SELECT tx_hash, block_number, block_timestamp, @@ -425,7 +418,7 @@ SELECT party_bmm, party_bs_white_list, position_type, - 'close' as action_type, + 'open' AS action_type, price, quantity, filled_amount, @@ -436,10 +429,53 @@ SELECT _inserted_timestamp, ez_decoded_event_logs_id, {{ dbt_utils.generate_surrogate_key( - ['tx_hash', 'quote_id'] + ['_log_id', 'quote_id'] ) }} AS symmio_perps_id, SYSDATE() AS inserted_timestamp, SYSDATE() AS modified_timestamp, '{{ invocation_id }}' AS _invocation_id -FROM - close_status \ No newline at end of file +FROM + quote_status +UNION ALL +SELECT + tx_hash, + block_number, + block_timestamp, + origin_from_address, + origin_to_address, + contract_address, + event_name, + event_index, + origin_function_signature, + decoded_log, + topic_0, + product_id, + status, + cva, + deadline, + lf, + market_price, + order_type, + party_a, + party_amm, + party_bmm, + party_bs_white_list, + position_type, + 'close' AS action_type, + price, + quantity, + filled_amount, + quote_id, + trading_fee, + product_name, + _log_id, + _inserted_timestamp, + ez_decoded_event_logs_id, + {{ dbt_utils.generate_surrogate_key( + ['_log_id', 'quote_id'] + ) }} AS symmio_perps_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id +FROM + close_status diff --git a/models/silver/protocols/pear/silver_pear__account_discounts_rebates.sql b/models/silver/protocols/pear/silver_pear__account_discounts_rebates.sql index f8becaf..0cf3780 100644 --- a/models/silver/protocols/pear/silver_pear__account_discounts_rebates.sql +++ b/models/silver/protocols/pear/silver_pear__account_discounts_rebates.sql @@ -85,5 +85,5 @@ LEFT JOIN fee_tiers f ON c.staked_amount >= f.stake_requirement LEFT JOIN vol_tier v ON monthly_volume >= v.monthly_vol_requirement -GROUP BY 1,2,3 +GROUP BY month, c.user_address, c.staked_amount ORDER BY c.staked_amount DESC \ No newline at end of file diff --git a/models/silver/protocols/pear/silver_pear__account_stats.sql b/models/silver/protocols/pear/silver_pear__account_stats.sql index f3f1b26..700cc04 100644 --- a/models/silver/protocols/pear/silver_pear__account_stats.sql +++ b/models/silver/protocols/pear/silver_pear__account_stats.sql @@ -207,7 +207,31 @@ referrals AS ( {{ ref('silver_pear__referrals') }} ) SELECT - f.*, + f.trader, + f.first_trade_timestamp, + f.last_trade_timestamp, + f.account_age, + f.trade_count, + f.trade_count_mtd, + f.gmx_trade_count, + f.symmio_trade_count, + f.vertex_trade_count, + f.perp_trade_count, + f.long_count, + f.short_count, + f.total_usd_volume, + f.total_usd_volume_24h, + f.total_usd_volume_mtd, + f.avg_usd_trade_size, + f.total_fee_amount, + f.total_liquidation_amount, + f.total_liquidation_count, + f.current_rebate_rate, + f.current_rebate_tier, + f.estimated_rebate_amount, + f.most_recent_staked_amount, + f.current_fee_discount_rate, + f._inserted_timestamp, r.referrer as referred_by, {{ dbt_utils.generate_surrogate_key(['f.trader']) }} AS pear_account_id, COALESCE( diff --git a/models/silver/protocols/pear/silver_pear__apr.sql b/models/silver/protocols/pear/silver_pear__apr.sql index 44f6ea2..df4775e 100644 --- a/models/silver/protocols/pear/silver_pear__apr.sql +++ b/models/silver/protocols/pear/silver_pear__apr.sql @@ -22,7 +22,7 @@ WITH depositstakerfee AS ( '-', event_index ) AS _log_id, - modified_timestamp + modified_timestamp AS _inserted_timestamp FROM {{ ref('core__ez_decoded_event_logs') }} WHERE @@ -31,13 +31,13 @@ WITH depositstakerfee AS ( AND tx_succeeded {% if is_incremental() %} -AND modified_timestamp >= ( +AND _inserted_timestamp >= ( SELECT - MAX(DAY) - INTERVAL '12 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) -AND modified_timestamp >= SYSDATE() - INTERVAL '7 day' +AND _inserted_timestamp >= SYSDATE() - INTERVAL '7 day' {% endif %} ), daily_staker_fee AS ( @@ -59,8 +59,7 @@ daily_price AS ( {{ ref('price__ez_prices_hourly') }} WHERE token_address IN ( - '0x82af49447d8a07e3bd95bd0d56f35241523fbab1', - -- weth + '0x82af49447d8a07e3bd95bd0d56f35241523fbab1',-- weth '0x3212dc0f8c834e4de893532d27cc9b6001684db0' -- pear ) GROUP BY @@ -90,6 +89,7 @@ SELECT {{ dbt_utils.generate_surrogate_key( ['day'] ) }} AS pear_daily_apr_id, + _inserted_timestamp, SYSDATE() AS inserted_timestamp, SYSDATE() AS modified_timestamp, '{{ invocation_id }}' AS _invocation_id diff --git a/models/silver/protocols/pear/silver_pear__referrals.sql b/models/silver/protocols/pear/silver_pear__referrals.sql index ed295b3..bf44d98 100644 --- a/models/silver/protocols/pear/silver_pear__referrals.sql +++ b/models/silver/protocols/pear/silver_pear__referrals.sql @@ -27,12 +27,22 @@ WITH referral_code_added AS ( '-', event_index ) AS _log_id, - modified_timestamp + modified_timestamp AS _inserted_timestamp FROM {{ ref('core__fact_event_logs') }} WHERE contract_address = '0x61126e4dcecbc7a43ac9fd783ccf66c62d9622fe' AND topic_0 = '0xd857c02cc639c01db6b14a3ff9f6c625012fdaa73829efa32719b3ebb4144968' + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '12 hours' + FROM + {{ this }} +) +AND _inserted_timestamp >= SYSDATE() - INTERVAL '7 day' +{% endif %} ), referee_added AS ( SELECT @@ -54,7 +64,7 @@ referee_added AS ( '-', event_index ) AS _log_id, - modified_timestamp + modified_timestamp AS _inserted_timestamp FROM {{ ref('core__fact_event_logs') }} WHERE @@ -62,13 +72,13 @@ referee_added AS ( AND topic_0 = '0x8729039de96215ec6db4a7775708511e52c141a25c89b9e69e97fca70c196d65' {% if is_incremental() %} -AND modified_timestamp >= ( +AND _inserted_timestamp >= ( SELECT - MAX(modified_timestamp) - INTERVAL '12 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) -AND modified_timestamp >= SYSDATE() - INTERVAL '7 day' +AND _inserted_timestamp >= SYSDATE() - INTERVAL '7 day' {% endif %} ), FINAL AS ( @@ -84,7 +94,8 @@ FINAL AS ( referee, referrer, arbitrum.utils.udf_hex_to_string(SUBSTRING(code, 3)) AS referral_code, - r._log_id + r._log_id, + r._inserted_timestamp FROM referral_code_added C RIGHT JOIN referee_added r USING(code) @@ -92,6 +103,7 @@ FINAL AS ( SELECT *, {{ dbt_utils.generate_surrogate_key(['referrer', 'referee']) }} AS referral_id, + _inserted_timestamp, SYSDATE() AS inserted_timestamp, SYSDATE() AS modified_timestamp, '{{invocation_id}}' AS _invocation_id diff --git a/models/silver/protocols/pear/silver_pear__staking.sql b/models/silver/protocols/pear/silver_pear__staking.sql index 64e32e9..15726b7 100644 --- a/models/silver/protocols/pear/silver_pear__staking.sql +++ b/models/silver/protocols/pear/silver_pear__staking.sql @@ -19,7 +19,7 @@ WITH logs_pull AS ( topic_0, topic_1, DATA, - modified_timestamp, + modified_timestamp AS _inserted_timestamp, CONCAT( tx_hash, '-', @@ -43,13 +43,13 @@ WITH logs_pull AS ( AND tx_succeeded {% if is_incremental() %} -AND modified_timestamp >= ( +AND _inserted_timestamp >= ( SELECT - MAX(modified_timestamp) - INTERVAL '12 hours' + MAX(_inserted_timestamp) - INTERVAL '12 hours' FROM {{ this }} ) -AND modified_timestamp >= SYSDATE() - INTERVAL '7 day' +AND _inserted_timestamp >= SYSDATE() - INTERVAL '7 day' {% endif %} ), unstaked AS ( @@ -75,7 +75,7 @@ unstaked AS ( -18 ) AS exitFee, 'PEAR' AS reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM logs_pull @@ -102,7 +102,7 @@ staked AS ( ) AS amount, 0 AS exitFee, 'PEAR' AS reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM logs_pull @@ -136,7 +136,7 @@ claims AS ( WHEN topic_0 = '0xd0738c40db6944b0431635619e5439399d30b1c3201de82a76281ad5e589a331' THEN 'ETH' WHEN topic_0 = '0xaaec67f0cf2b4350aec177973525b594b0ef343afc049ce70b0808e96a1b5e64' THEN 'PEAR' END AS reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM logs_pull @@ -172,7 +172,7 @@ compound AS ( 10, -18 ) AS exitFeeReward, - modified_timestamp, + _inserted_timestamp, _log_id FROM logs_pull @@ -194,7 +194,7 @@ compound_split AS ( user_address, rewardsInEth AS amount, 'ETH' AS reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM compound @@ -213,7 +213,7 @@ compound_split AS ( user_address, exitFeeReward AS amount, 'PEAR' AS reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM compound @@ -230,7 +230,7 @@ FINAL AS ( user_address, amount, reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM unstaked @@ -246,7 +246,7 @@ FINAL AS ( user_address, amount, reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM staked @@ -262,7 +262,7 @@ FINAL AS ( user_address, amount, reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM claims @@ -278,7 +278,7 @@ FINAL AS ( user_address, amount, reward_token, - modified_timestamp, + _inserted_timestamp, _log_id FROM compound_split @@ -294,7 +294,7 @@ SELECT user_address, amount, reward_token, - modified_timestamp as _inserted_timestamp, + _inserted_timestamp, _log_id, {{ dbt_utils.generate_surrogate_key( ['_log_id']