diff --git a/dbt_subprojects/dex/models/_projects/cow_protocol/base/cow_protocol_base_trades.sql b/dbt_subprojects/dex/models/_projects/cow_protocol/base/cow_protocol_base_trades.sql index e4ba29faa0a..563a94b8b81 100644 --- a/dbt_subprojects/dex/models/_projects/cow_protocol/base/cow_protocol_base_trades.sql +++ b/dbt_subprojects/dex/models/_projects/cow_protocol/base/cow_protocol_base_trades.sql @@ -16,6 +16,31 @@ }} WITH +atokens_mapping as ( + SELECT + DISTINCT 'base' as blockchain, + aToken as atoken_address, + asset as underlying_address + FROM {{source('aave_v3_base','poolconfigurator_evt_reserveinitialized')}} +), + +atoken_prices as ( + SELECT + atkm.atoken_address as contract_address, + prc.price, + prc.minute, + prc.blockchain + FROM atokens_mapping as atkm + INNER JOIN {{ source('prices', 'usd') }} as prc + ON atkm.underlying_address = prc.contract_address + WHERE atkm.blockchain = 'base' + and prc.blockchain = 'base' + {% if is_incremental() %} + AND {{ incremental_predicate('minute') }} + {% endif %} + +), + -- First subquery joins buy and sell token prices from prices.usd. -- Also deducts fee from sell amount. trades_with_prices AS ( @@ -33,28 +58,45 @@ trades_with_prices AS ( sellAmount - feeAmount as sell_amount, buyAmount as buy_amount, feeAmount as fee_amount, - ps.price as sell_price, - pb.price as buy_price + coalesce(ps.price, atoken_ps.price) as sell_price, + coalesce(pb.price, atoken_pb.price) as buy_price FROM {{ source('gnosis_protocol_v2_base', 'GPv2Settlement_evt_Trade') }} trade - LEFT OUTER JOIN {{ source('prices', 'usd') }} as ps - ON sellToken = ps.contract_address - AND ps.minute = date_trunc('minute', evt_block_time) - AND ps.blockchain = 'base' - {% if is_incremental() %} - AND {{ incremental_predicate('ps.minute') }} - {% endif %} - LEFT OUTER JOIN {{ source('prices', 'usd') }} as pb - ON pb.contract_address = ( - CASE - WHEN buyToken = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee - THEN 0x4200000000000000000000000000000000000006 - ELSE buyToken - END) - AND pb.minute = date_trunc('minute', evt_block_time) - AND pb.blockchain = 'base' - {% if is_incremental() %} - AND {{ incremental_predicate('pb.minute') }} - {% endif %} + LEFT OUTER JOIN {{ source('prices', 'usd') }} as ps + ON + sellToken = ps.contract_address + AND ps.minute = date_trunc('minute', evt_block_time) + AND ps.blockchain = 'base' + {% if is_incremental() %} + AND {{ incremental_predicate('ps.minute') }} + {% endif %} + LEFT OUTER JOIN {{ source('prices', 'usd') }} as pb + ON + pb.contract_address = ( + CASE + WHEN buyToken = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee + THEN 0x4200000000000000000000000000000000000006 + ELSE buyToken + END + ) + AND pb.minute = date_trunc('minute', evt_block_time) + AND pb.blockchain = 'base' + {% if is_incremental() %} + AND {{ incremental_predicate('pb.minute') }} + {% endif %} + LEFT OUTER JOIN atoken_prices as atoken_pb + ON + atoken_pb.contract_address = ( + CASE + WHEN buyToken = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee + THEN 0x4200000000000000000000000000000000000006 + ELSE buyToken + END + ) + AND atoken_pb.minute = date_trunc('minute', evt_block_time) + LEFT OUTER JOIN atoken_prices as atoken_ps + ON + atoken_ps.contract_address = sellToken + AND atoken_ps.minute = date_trunc('minute', evt_block_time) WHERE 1 = 1 -- to keep where clause clean with incremental predicate AND evt_tx_hash != 0xd5c5c3e91e2c0c0552178fccf6af790e692fb9dbf1930df5558c626f0c0ee097 -- known outlier tx which causes UINT256 overflow in surplus_usd calculation downstream diff --git a/sources/aave/base/aave_base_sources.yml b/sources/aave/base/aave_base_sources.yml index 2ae1a4c0f51..a035b160d1d 100644 --- a/sources/aave/base/aave_base_sources.yml +++ b/sources/aave/base/aave_base_sources.yml @@ -6,3 +6,5 @@ sources: tables: - name: StataToken_evt_Initialized - name: StataTokenFactory_call_createDeterministic + - name: poolconfigurator_evt_reserveinitialized +