From cf6e6d59d04671c11c54fe8f19a4c8d5bf35f0aa Mon Sep 17 00:00:00 2001 From: Vahid-flipside <98771482+Vahid-flipside@users.noreply.github.com> Date: Tue, 30 Aug 2022 16:33:23 -0400 Subject: [PATCH] improving sushi tables (#15) --- models/sushi/sushi__ez_borrowing.sql | 130 +++++++++++++++++++++++---- models/sushi/sushi__ez_borrowing.yml | 2 +- models/sushi/sushi__ez_lending.sql | 4 +- models/sushi/sushi__ez_lending.yml | 2 +- models/sushi/sushi__ez_swaps.sql | 15 ++-- models/sushi/sushi__ez_swaps.yml | 2 +- 6 files changed, 126 insertions(+), 29 deletions(-) diff --git a/models/sushi/sushi__ez_borrowing.sql b/models/sushi/sushi__ez_borrowing.sql index 3338991..02460e6 100644 --- a/models/sushi/sushi__ez_borrowing.sql +++ b/models/sushi/sushi__ez_borrowing.sql @@ -11,7 +11,7 @@ with borrow_txns as ( select distinct tx_hash,contract_address from {{ ref('silver__logs') }} -where event_name = 'LogBorrow' +where topics [0]::string = '0x3a5151e57d3bc9798e7853034ac52293d1a0e12a2b44725e75b03b21f86477a6' {% if is_incremental() %} AND _inserted_timestamp::DATE >= ( SELECT @@ -25,7 +25,7 @@ AND _inserted_timestamp::DATE >= ( Repay_txns as ( select distinct tx_hash,contract_address from {{ ref('silver__logs') }} -where event_name = 'LogRepay' +where topics [0]::string = '0xc8e512d8f188ca059984b5853d2bf653da902696b8512785b182b2c813789a6e' {% if is_incremental() %} AND _inserted_timestamp::DATE >= ( SELECT @@ -36,7 +36,7 @@ AND _inserted_timestamp::DATE >= ( {% endif %} ), -Borrow as ( +Borrow0 as ( select block_timestamp, block_number, tx_hash, @@ -70,7 +70,39 @@ AND _inserted_timestamp::DATE >= ( ), -Repay as ( +pay_coll as ( +select tx_hash, + concat ('0x', SUBSTR(topics [1] :: STRING, 27, 40)) as collateral, + CONCAT('0x', SUBSTR(topics [3] :: STRING, 27, 40)) as Lending_pool_address, + TRY_TO_NUMBER( + public.udf_hex_to_int(SUBSTR(DATA, 3, len(DATA)))::integer + ) as collateral_amount, + _inserted_timestamp +from {{ ref('silver__logs') }} +where topics [0]::string = '0x6eabe333476233fd382224f233210cb808a7bc4c4de64f9d76628bf63c677b1a' and tx_hash in (select tx_hash from borrow_txns) +and CONCAT('0x', SUBSTR(topics [3] :: STRING, 27, 40)) in (select pair_address from {{ ref('sushi__dim_kashi_pairs') }} ) +{% if is_incremental() %} +AND _inserted_timestamp::DATE >= ( + SELECT + MAX(_inserted_timestamp) ::DATE - 2 + FROM + {{ this }} +) +{% endif %} + +), + +Borrow as +( +select a.*, b.collateral_amount, b.collateral as collateral_address +from Borrow0 a +left join pay_coll b +on a.tx_hash = b.tx_hash and a.lending_pool_address = b.lending_pool_address +), + + + +Repay0 as ( select block_timestamp, block_number, tx_hash, @@ -103,14 +135,43 @@ AND _inserted_timestamp::DATE >= ( {% endif %} ), -Final as ( + +receive_coll as ( +select tx_hash, + CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) as collateral, + CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) as Lending_pool_address, + TRY_TO_NUMBER( + public.udf_hex_to_int(SUBSTR(DATA, 3, len(DATA)))::integer + ) as collateral_amount, + _inserted_timestamp +from {{ ref('silver__logs') }} +where topics [0]::string = '0x6eabe333476233fd382224f233210cb808a7bc4c4de64f9d76628bf63c677b1a' and tx_hash in (select tx_hash from Repay_txns) +and CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) in (select pair_address from {{ ref('sushi__dim_kashi_pairs') }} ) +{% if is_incremental() %} +AND _inserted_timestamp::DATE >= ( + SELECT + MAX(_inserted_timestamp) ::DATE - 2 + FROM + {{ this }} +) +{% endif %} +), + +Repay as +( +select a.*, b.collateral_amount, b.collateral as collateral_address +from Repay0 a +left join receive_coll b +on a.tx_hash = b.tx_hash and a.lending_pool_address = b.lending_pool_address +), + +Total as ( select * from Borrow union all select * from Repay ), - - Arbitrum_prices AS ( + prices AS ( select symbol, date_trunc('hour',recorded_at) as hour, @@ -136,6 +197,31 @@ AND hour :: DATE IN ( ), + collateral_prices AS ( + select + symbol, + date_trunc('hour',recorded_at) as hour, + avg(price) as collateral_price + from + {{ source('prices','prices_v2') }} a + join {{ ref('sushi__dim_kashi_pairs') }} b + on a.symbol = b.collateral_symbol + WHERE + 1 = 1 + +{% if is_incremental() %} +AND hour :: DATE IN ( + SELECT + DISTINCT block_timestamp :: DATE + FROM + borrow +) +{% else %} + AND hour :: DATE >= '2021-09-01' +{% endif %} + group by 1,2 +), + labels as ( @@ -143,6 +229,7 @@ select * from {{ ref('sushi__dim_kashi_pairs') }} ), + Labled_WO_prices as ( select a.block_timestamp, @@ -159,12 +246,14 @@ a.lending_pool_address, a.event_index, b.asset_decimals, case when b.asset_decimals is null then a.amount else (a.amount/pow(10,b.asset_decimals)) end as asset_amount, +case when b.collateral_decimals is null then a.collateral_amount else (a.collateral_amount/pow(10,b.collateral_decimals)) end as collateral_amount, b.pair_name as lending_pool, b.asset_symbol as symbol, a._log_id, substring(b.pair_name,3,charindex('/',b.pair_name)-3) as collateral_symbol, +a.collateral_address, _inserted_timestamp -from FINAL a +from Total a left join labels b on a.Lending_pool_address = b.pair_address ) @@ -179,25 +268,32 @@ a.action, a.origin_from_address, a.origin_to_address, a.origin_function_signature, -a.asset, a.Borrower, a.Borrower_is_a_contract, a.lending_pool_address, a.event_index, -a.asset_amount, a.lending_pool, +a.asset, a.symbol, -a._log_id, +a.asset_amount, +(a.asset_amount* c.price) as asset_amount_USD , +a.collateral_address, a.collateral_symbol, -case --when c.price is null then null - when a.asset_Decimals is null then null - else (a.asset_amount* c.price) - end as asset_amount_USD , +a.collateral_amount, +(a.collateral_amount* d.collateral_price) as collateral_amount_USD, +a._log_id, _inserted_timestamp from Labled_WO_prices a -LEFT JOIN Arbitrum_prices c +LEFT JOIN prices c ON a.symbol = c.symbol AND DATE_TRUNC( 'hour', a.block_timestamp -) = c.hour \ No newline at end of file +) = c.hour + +LEFT JOIN collateral_prices d +ON a.symbol = d.symbol +AND DATE_TRUNC( + 'hour', + a.block_timestamp +) = d.hour \ No newline at end of file diff --git a/models/sushi/sushi__ez_borrowing.yml b/models/sushi/sushi__ez_borrowing.yml index 0b60497..c4adb4b 100644 --- a/models/sushi/sushi__ez_borrowing.yml +++ b/models/sushi/sushi__ez_borrowing.yml @@ -21,7 +21,7 @@ models: - not_null - dbt_expectations.expect_row_values_to_have_recent_data: datepart: day - interval: 7 #borrowing transactions are not very frequent + interval: 30 #borrowing transactions are not very frequent - dbt_expectations.expect_column_values_to_be_in_type_list: column_type_list: - TIMESTAMP_NTZ diff --git a/models/sushi/sushi__ez_lending.sql b/models/sushi/sushi__ez_lending.sql index c1af9bb..176bc1c 100644 --- a/models/sushi/sushi__ez_lending.sql +++ b/models/sushi/sushi__ez_lending.sql @@ -103,7 +103,7 @@ AND _inserted_timestamp::DATE >= ( {% endif %} ), -Final as ( +Total as ( select * from Lending union all select * from Withdraw @@ -163,7 +163,7 @@ b.pair_name as lending_pool, b.asset_symbol as symbol, a._log_id, _inserted_timestamp -from FINAL a +from Total a left join labels b on a.Lending_pool_address = b.pair_address ) diff --git a/models/sushi/sushi__ez_lending.yml b/models/sushi/sushi__ez_lending.yml index 2936e15..9af9c1e 100644 --- a/models/sushi/sushi__ez_lending.yml +++ b/models/sushi/sushi__ez_lending.yml @@ -22,7 +22,7 @@ models: - not_null - dbt_expectations.expect_row_values_to_have_recent_data: datepart: day - interval: 7 #lending transactions are not very frequent + interval: 30 #lending transactions are not very frequent - dbt_expectations.expect_column_values_to_be_in_type_list: column_type_list: - TIMESTAMP_NTZ diff --git a/models/sushi/sushi__ez_swaps.sql b/models/sushi/sushi__ez_swaps.sql index 7371fc1..145f4fa 100644 --- a/models/sushi/sushi__ez_swaps.sql +++ b/models/sushi/sushi__ez_swaps.sql @@ -17,27 +17,28 @@ WITH swap_events AS ( tx_hash, contract_address, event_name, + regexp_substr_all(SUBSTR(DATA, 3, len(DATA)), '.{64}') AS segmented_data, TRY_TO_NUMBER( - event_inputs :amount0In :: STRING + public.udf_hex_to_int(segmented_data[0]::string)::integer ) AS amount0In, TRY_TO_NUMBER( - event_inputs :amount1In :: STRING + public.udf_hex_to_int(segmented_data[1]::string)::integer ) AS amount1In, TRY_TO_NUMBER( - event_inputs :amount0Out :: STRING + public.udf_hex_to_int(segmented_data[2]::string)::integer ) AS amount0Out, TRY_TO_NUMBER( - event_inputs :amount1Out :: STRING + public.udf_hex_to_int(segmented_data[3]::string)::integer ) AS amount1Out, - event_inputs :sender :: STRING AS sender, - event_inputs :to :: STRING AS tx_to, + CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) AS sender, + CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS tx_to, event_index, _log_id, _inserted_timestamp FROM {{ ref('silver__logs') }} WHERE - event_name = 'Swap' + topics[0]::string = '0xd78ad95fa46c994b6551d0da85fc275fe613ce37657fb8d5e3d130840159d822' AND tx_status = 'SUCCESS' AND contract_address IN ( SELECT diff --git a/models/sushi/sushi__ez_swaps.yml b/models/sushi/sushi__ez_swaps.yml index 2f764f4..77c625c 100644 --- a/models/sushi/sushi__ez_swaps.yml +++ b/models/sushi/sushi__ez_swaps.yml @@ -22,7 +22,7 @@ models: - not_null - dbt_expectations.expect_row_values_to_have_recent_data: datepart: day - interval: 2 #might be normal for swaps not to happen on a day + interval: 5 #might be normal for swaps not to happen on a day - dbt_expectations.expect_column_values_to_be_in_type_list: column_type_list: - TIMESTAMP_NTZ