From 403e34a3cdcb4f2c06d10b6551253ece7af4055e Mon Sep 17 00:00:00 2001 From: alexwes Date: Wed, 6 Nov 2024 12:27:08 -0500 Subject: [PATCH] Maple Metrics (#581) --- .../addresses/hex_string_to_evm_address.sql | 3 + macros/solana_utils/base58_to_hex.sql | 3 + .../big_endian_hex_to_decimal.sql | 3 + macros/solana_utils/hex_to_base58.sql | 3 + .../projects/maple/prod/ez_maple_metrics.sql | 109 +++++ .../maple/prod/ez_maple_metrics_by_chain.sql | 34 ++ .../maple/prod/ez_maple_metrics_by_pool.sql | 40 ++ .../maple/prod/ez_maple_metrics_by_token.sql | 98 +++++ .../jupiter/fact_jupiter_dca_fees_silver.sql | 6 +- .../jupiter/fact_jupiter_perps_txs.sql | 38 +- models/staging/maple/__maple__sources.yml | 24 ++ models/staging/maple/dim_maple_dates.sql | 13 + models/staging/maple/dim_maple_pools.sql | 32 ++ .../maple/dim_maple_v2_pool_deposit_pools.sql | 41 ++ .../maple/dim_maple_withdrawal_managers.sql | 30 ++ .../maple/fact_maple_Pool_evt_Claim.sql | 35 ++ .../maple/fact_maple_accounting_updates.sql | 50 +++ models/staging/maple/fact_maple_agg_tvl.sql | 38 ++ .../staging/maple/fact_maple_all_events.sql | 283 +++++++++++++ models/staging/maple/fact_maple_deposits.sql | 20 + models/staging/maple/fact_maple_fees.sql | 30 ++ .../staging/maple/fact_maple_interest_v1.sql | 32 ++ .../staging/maple/fact_maple_interest_v2.sql | 90 +++++ .../maple/fact_maple_offchain_data.sql | 374 ++++++++++++++++++ .../maple/fact_maple_onchain_revenue.sql | 30 ++ .../staging/maple/fact_maple_otc_by_day.sql | 40 ++ models/staging/maple/fact_maple_payments.sql | 44 +++ .../maple/fact_maple_pool_state_daily.sql | 134 +++++++ .../maple/fact_maple_pool_state_history.sql | 34 ++ .../maple/fact_maple_principal_updates.sql | 70 ++++ models/staging/maple/fact_maple_revenue.sql | 25 ++ .../maple/fact_maple_solana_by_day.sql | 21 + .../maple/fact_maple_token_incentives.sql | 36 ++ .../maple/fact_maple_tokenholder_count.sql | 8 + models/staging/maple/fact_maple_treasury.sql | 16 + ...maple_v1_FixedTermLoan_evt_PaymentMade.sql | 54 +++ .../fact_maple_v1_Loan_evt_PaymentMade.sql | 30 ++ .../maple/fact_maple_v1_Pool_LoanFunded.sql | 25 ++ models/staging/maple/fact_maple_v1_loans.sql | 18 + .../maple/fact_maple_v1_repayments.sql | 51 +++ models/staging/maple/fact_maple_v1_tvl.sql | 84 ++++ ..._maple_v2_LoanManager_FundsDistributed.sql | 25 ++ ...e_v2_LoanManager_IssuanceParamsUpdated.sql | 25 ++ ...ple_v2_LoanManager_PrincipalOutUpdated.sql | 38 ++ ...TermLoanManager_AccountingStateUpdated.sql | 24 ++ ...ermLoanManager_ClaimedFundsDistributed.sql | 29 ++ ...penTermLoanManager_PrincipalOutUpdated.sql | 38 ++ .../maple/fact_maple_v2_Pool_Deposit.sql | 30 ++ ...ueueWithdrawalManager_RequestProcessed.sql | 28 ++ ..._WithdrawalManager_WithdrawalProcessed.sql | 25 ++ ...t_maple_v2_loan_manager_manual_entries.sql | 14 + models/staging/maple/fact_maple_v2_tvl.sql | 79 ++++ .../staging/maple/fact_maple_withdrawals.sql | 46 +++ udfs/hex_string_to_evm_address_udf.sql | 30 ++ 54 files changed, 2559 insertions(+), 21 deletions(-) create mode 100644 macros/addresses/hex_string_to_evm_address.sql create mode 100644 macros/solana_utils/base58_to_hex.sql create mode 100644 macros/solana_utils/big_endian_hex_to_decimal.sql create mode 100644 macros/solana_utils/hex_to_base58.sql create mode 100644 models/projects/maple/prod/ez_maple_metrics.sql create mode 100644 models/projects/maple/prod/ez_maple_metrics_by_chain.sql create mode 100644 models/projects/maple/prod/ez_maple_metrics_by_pool.sql create mode 100644 models/projects/maple/prod/ez_maple_metrics_by_token.sql create mode 100644 models/staging/maple/__maple__sources.yml create mode 100644 models/staging/maple/dim_maple_dates.sql create mode 100644 models/staging/maple/dim_maple_pools.sql create mode 100644 models/staging/maple/dim_maple_v2_pool_deposit_pools.sql create mode 100644 models/staging/maple/dim_maple_withdrawal_managers.sql create mode 100644 models/staging/maple/fact_maple_Pool_evt_Claim.sql create mode 100644 models/staging/maple/fact_maple_accounting_updates.sql create mode 100644 models/staging/maple/fact_maple_agg_tvl.sql create mode 100644 models/staging/maple/fact_maple_all_events.sql create mode 100644 models/staging/maple/fact_maple_deposits.sql create mode 100644 models/staging/maple/fact_maple_fees.sql create mode 100644 models/staging/maple/fact_maple_interest_v1.sql create mode 100644 models/staging/maple/fact_maple_interest_v2.sql create mode 100644 models/staging/maple/fact_maple_offchain_data.sql create mode 100644 models/staging/maple/fact_maple_onchain_revenue.sql create mode 100644 models/staging/maple/fact_maple_otc_by_day.sql create mode 100644 models/staging/maple/fact_maple_payments.sql create mode 100644 models/staging/maple/fact_maple_pool_state_daily.sql create mode 100644 models/staging/maple/fact_maple_pool_state_history.sql create mode 100644 models/staging/maple/fact_maple_principal_updates.sql create mode 100644 models/staging/maple/fact_maple_revenue.sql create mode 100644 models/staging/maple/fact_maple_solana_by_day.sql create mode 100644 models/staging/maple/fact_maple_token_incentives.sql create mode 100644 models/staging/maple/fact_maple_tokenholder_count.sql create mode 100644 models/staging/maple/fact_maple_treasury.sql create mode 100644 models/staging/maple/fact_maple_v1_FixedTermLoan_evt_PaymentMade.sql create mode 100644 models/staging/maple/fact_maple_v1_Loan_evt_PaymentMade.sql create mode 100644 models/staging/maple/fact_maple_v1_Pool_LoanFunded.sql create mode 100644 models/staging/maple/fact_maple_v1_loans.sql create mode 100644 models/staging/maple/fact_maple_v1_repayments.sql create mode 100644 models/staging/maple/fact_maple_v1_tvl.sql create mode 100644 models/staging/maple/fact_maple_v2_LoanManager_FundsDistributed.sql create mode 100644 models/staging/maple/fact_maple_v2_LoanManager_IssuanceParamsUpdated.sql create mode 100644 models/staging/maple/fact_maple_v2_LoanManager_PrincipalOutUpdated.sql create mode 100644 models/staging/maple/fact_maple_v2_OpenTermLoanManager_AccountingStateUpdated.sql create mode 100644 models/staging/maple/fact_maple_v2_OpenTermLoanManager_ClaimedFundsDistributed.sql create mode 100644 models/staging/maple/fact_maple_v2_OpenTermLoanManager_PrincipalOutUpdated.sql create mode 100644 models/staging/maple/fact_maple_v2_Pool_Deposit.sql create mode 100644 models/staging/maple/fact_maple_v2_QueueWithdrawalManager_RequestProcessed.sql create mode 100644 models/staging/maple/fact_maple_v2_WithdrawalManager_WithdrawalProcessed.sql create mode 100644 models/staging/maple/fact_maple_v2_loan_manager_manual_entries.sql create mode 100644 models/staging/maple/fact_maple_v2_tvl.sql create mode 100644 models/staging/maple/fact_maple_withdrawals.sql create mode 100644 udfs/hex_string_to_evm_address_udf.sql diff --git a/macros/addresses/hex_string_to_evm_address.sql b/macros/addresses/hex_string_to_evm_address.sql new file mode 100644 index 00000000..7172b6cf --- /dev/null +++ b/macros/addresses/hex_string_to_evm_address.sql @@ -0,0 +1,3 @@ +{% macro hex_string_to_evm_address(hex_string) %} + PC_DBT_DB.PROD.HEX_STRING_TO_EVM_ADDRESS({{ hex_string }}) +{% endmacro %} diff --git a/macros/solana_utils/base58_to_hex.sql b/macros/solana_utils/base58_to_hex.sql new file mode 100644 index 00000000..6395249d --- /dev/null +++ b/macros/solana_utils/base58_to_hex.sql @@ -0,0 +1,3 @@ +{% macro base58_to_hex(base58_string) %} + PC_DBT_DB.PROD.BASE58_TO_HEX({{ base58_string }}) +{% endmacro %} diff --git a/macros/solana_utils/big_endian_hex_to_decimal.sql b/macros/solana_utils/big_endian_hex_to_decimal.sql new file mode 100644 index 00000000..bb9fa0da --- /dev/null +++ b/macros/solana_utils/big_endian_hex_to_decimal.sql @@ -0,0 +1,3 @@ +{% macro big_endian_hex_to_decimal(hex_string) %} + PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL({{ hex_string }}) +{% endmacro %} diff --git a/macros/solana_utils/hex_to_base58.sql b/macros/solana_utils/hex_to_base58.sql new file mode 100644 index 00000000..6b19d864 --- /dev/null +++ b/macros/solana_utils/hex_to_base58.sql @@ -0,0 +1,3 @@ +{% macro hex_to_base58(hex_string) %} + PC_DBT_DB.PROD.HEX_TO_BASE58({{ hex_string }}) +{% endmacro %} diff --git a/models/projects/maple/prod/ez_maple_metrics.sql b/models/projects/maple/prod/ez_maple_metrics.sql new file mode 100644 index 00000000..8abf1f78 --- /dev/null +++ b/models/projects/maple/prod/ez_maple_metrics.sql @@ -0,0 +1,109 @@ + +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + database='MAPLE', + schema='core', + alias='ez_metrics' + ) +}} + + + +with fees as ( + SELECT + date, + SUM(net_interest_usd) AS fees, + SUM(net_interest_usd) AS supply_side_fees, + SUM(platform_fees_usd) AS platform_fees, + SUM(delegate_fees_usd) AS delegate_fees + FROM {{ ref('fact_maple_fees') }} + GROUP BY 1 +) +, revenues as ( + SELECT + date, + SUM(revenue) AS revenue + FROM {{ ref('fact_maple_revenue') }} + GROUP BY 1 +) +, token_incentives as ( + SELECT + DATE(block_timestamp) AS date, + SUM(incentive_usd) AS token_incentives + FROM {{ ref('fact_maple_token_incentives') }} + GROUP BY 1 +) +, tvl as ( + SELECT + date, + SUM(tvl) AS tvl, + SUM(outstanding_supply) AS outstanding_supply + FROM {{ ref('fact_maple_agg_tvl') }} + GROUP BY 1 +) +, treasury as ( + SELECT + date, + SUM(usd_balance) AS treasury_value + FROM {{ ref('fact_maple_treasury') }} + GROUP BY 1 +) +, net_treasury as ( + SELECT + date, + SUM(usd_balance) AS net_treasury_value + FROM {{ ref('fact_maple_treasury') }} + WHERE token <> 'MPL' + GROUP BY 1 +) +, treasury_native as ( + SELECT + date, + SUM(native_balance) AS treasury_value_native + FROM {{ ref('fact_maple_treasury') }} + WHERE token = 'MPL' + GROUP BY 1 +) +, price as( + {{ get_coingecko_metrics('maple')}} +) +, tokenholders as ( + SELECT * FROM {{ ref('fact_maple_tokenholder_count')}} +) + +SELECT + price.date, + coalesce(fees.fees, 0) as interest_fees, + coalesce(fees.platform_fees, 0) as platform_fees, + coalesce(fees.delegate_fees, 0) as delegate_fees, + coalesce(fees.fees, 0) as fees, + coalesce(interest_fees, 0) - coalesce(platform_fees, 0) - coalesce(delegate_fees, 0) as primary_supply_side_revenue, + coalesce(primary_supply_side_revenue, 0) as total_supply_side_revenue, + coalesce(revenues.revenue, 0) as revenue, + coalesce(token_incentives.token_incentives, 0) as token_incentives, + coalesce(token_incentives.token_incentives, 0) as total_expenses, + coalesce(revenue, 0) - coalesce(total_expenses, 0) as protocol_earnings, + coalesce(treasury.treasury_value, 0) as treasury_value, + coalesce(treasury_native.treasury_value_native, 0) as treasury_value_native, + coalesce(net_treasury.net_treasury_value, 0) as net_treasury_value, + coalesce(tvl.tvl, 0) as tvl, + coalesce(tvl.tvl, 0) as net_deposits, + coalesce(tvl.outstanding_supply, 0) as outstanding_supply, + coalesce(price.price, 0) as price, + coalesce(price.market_cap, 0) as market_cap, + coalesce(price.fdmc, 0) as fdmc, + price.token_turnover_circulating, + price.token_turnover_fdv, + price.token_volume, + tokenholders.token_holder_count +FROM price +LEFT JOIN fees USING(date) +LEFT JOIN revenues USING(date) +LEFT JOIN token_incentives USING(date) +LEFT JOIN tvl USING(date) +LEFT JOIN treasury USING(date) +LEFT JOIN treasury_native USING(date) +LEFT JOIN net_treasury USING(date) +LEFT JOIN tokenholders USING(date) \ No newline at end of file diff --git a/models/projects/maple/prod/ez_maple_metrics_by_chain.sql b/models/projects/maple/prod/ez_maple_metrics_by_chain.sql new file mode 100644 index 00000000..b7330ebd --- /dev/null +++ b/models/projects/maple/prod/ez_maple_metrics_by_chain.sql @@ -0,0 +1,34 @@ +{{ + config( + materialized = 'view', + snowflake_warehouse = 'MAPLE', + database = 'MAPLE', + schema = 'core', + alias = 'ez_metrics_by_chain' + ) +}} + +SELECT + date, + 'ethereum' as chain, + interest_fees, + primary_supply_side_revenue, + total_supply_side_revenue, + revenue, + token_incentives, + total_expenses, + protocol_earnings, + treasury_value, + treasury_value_native, + net_treasury_value, + tvl, + net_deposits, + outstanding_supply, + price, + market_cap, + fdmc, + token_turnover_circulating, + token_turnover_fdv, + token_volume, + token_holder_count +FROM {{ ref('ez_maple_metrics') }} \ No newline at end of file diff --git a/models/projects/maple/prod/ez_maple_metrics_by_pool.sql b/models/projects/maple/prod/ez_maple_metrics_by_pool.sql new file mode 100644 index 00000000..b2f2009a --- /dev/null +++ b/models/projects/maple/prod/ez_maple_metrics_by_pool.sql @@ -0,0 +1,40 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + database='MAPLE', + schema='core', + alias='ez_metrics_by_pool' + ) +}} + +with fees as ( + SELECT + date, + pool_name, + SUM(net_interest_usd) AS fees, + SUM(platform_fees_usd) AS platform_fees, + SUM(delegate_fees_usd) AS delegate_fees + FROM {{ ref('fact_maple_fees') }} + GROUP BY 1, 2 +) +, tvl as ( + SELECT + date, + pool_name, + SUM(tvl_native) AS tvl_native, + SUM(tvl) AS tvl, + SUM(outstanding_supply) AS outstanding_supply + FROM {{ ref('fact_maple_agg_tvl') }} + GROUP BY 1, 2 +) +SELECT + coalesce(fees.date, tvl.date) as date, + coalesce(fees.pool_name, tvl.pool_name) as pool_name, + fees.fees, + fees.platform_fees, + fees.delegate_fees, + tvl.tvl, + tvl.outstanding_supply +FROM fees +FULL OUTER JOIN tvl ON fees.date = tvl.date AND fees.pool_name = tvl.pool_name \ No newline at end of file diff --git a/models/projects/maple/prod/ez_maple_metrics_by_token.sql b/models/projects/maple/prod/ez_maple_metrics_by_token.sql new file mode 100644 index 00000000..6fbba13c --- /dev/null +++ b/models/projects/maple/prod/ez_maple_metrics_by_token.sql @@ -0,0 +1,98 @@ + +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + database='MAPLE', + schema='core', + alias='ez_metrics_by_token' + ) +}} + +with fees as ( + SELECT + date, + asset as token, + SUM(net_interest_native) AS fees_native, + SUM(platform_fees_native) AS platform_fees_native, + SUM(delegate_fees_native) AS delegate_fees_native + FROM {{ ref('fact_maple_fees') }} + GROUP BY 1, 2 +) +, revenues as ( + SELECT + date, + token, + SUM(revenue_native) AS revenue_native + FROM {{ ref('fact_maple_revenue') }} + GROUP BY 1, 2 +) +, token_incentives as ( + SELECT + DATE(block_timestamp) AS date, + token, + SUM(incentive_native) AS token_incentives_native + FROM {{ ref('fact_maple_token_incentives') }} + GROUP BY 1, 2 +) +, tvl as ( + SELECT + date, + asset as token, + SUM(tvl_native) AS tvl_native + FROM {{ ref('fact_maple_agg_tvl') }} + GROUP BY 1, 2 +) +, treasury as ( + SELECT + date, + token, + SUM(native_balance) AS treasury_value_native + FROM {{ ref('fact_maple_treasury') }} + GROUP BY 1, 2 +) +, treasury_native as ( + SELECT + date, + token, + SUM(native_balance) AS treasury_native + FROM {{ ref('fact_maple_treasury') }} + WHERE token = 'MPL' + GROUP BY 1, 2 +) +, net_treasury as ( + SELECT + date, + token, + SUM(native_balance) AS net_treasury_value + FROM {{ ref('fact_maple_treasury') }} + WHERE token <> 'MPL' + GROUP BY 1, 2 +) + +SELECT + coalesce(fees.date, revenues.date, token_incentives.date, tvl.date, treasury.date) as date, + coalesce(fees.token, revenues.token, token_incentives.token, tvl.token, treasury.token) as token, + fees.fees_native as interest_fees_native, + fees.platform_fees_native as platform_fees_native, + fees.delegate_fees_native as delegate_fees_native, + fees.fees_native - fees.platform_fees_native - fees.delegate_fees_native as supply_side_revenue_native, + supply_side_revenue_native as total_supply_side_revenue_native, + revenues.revenue_native, + token_incentives.token_incentives_native, + token_incentives.token_incentives_native as expenses_native, + revenues.revenue_native - token_incentives.token_incentives_native as protocol_earnings_native + , tvl.tvl_native + , tvl.tvl_native as net_deposits_native + , treasury.treasury_value_native + , treasury_native.treasury_native + , net_treasury.net_treasury_value +FROM + fees +full join revenues using(date, token) +full join token_incentives using(date, token) +full join tvl using(date, token) +full join treasury using(date, token) +full join treasury_native using(date, token) +full join net_treasury using(date, token) +WHERE coalesce(fees.date, revenues.date, token_incentives.date, tvl.date, treasury.date) < to_date(sysdate()) diff --git a/models/staging/jupiter/fact_jupiter_dca_fees_silver.sql b/models/staging/jupiter/fact_jupiter_dca_fees_silver.sql index fa4f79bb..f3d6d8fa 100644 --- a/models/staging/jupiter/fact_jupiter_dca_fees_silver.sql +++ b/models/staging/jupiter/fact_jupiter_dca_fees_silver.sql @@ -9,7 +9,7 @@ with hex_cte as( SELECT date(block_timestamp) as date, - PC_DBT_DB.PROD.BASE58_TO_HEX(f.value:data) as hex_data, + {{ base58_to_hex("f.value:data") }} as hex_data, f.value:data as base58_data, tx_id FROM @@ -28,8 +28,8 @@ with hex_cte as( processed_ic as( -- processed hex data SELECT date, - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,224+1,16)) as amount, -- fee amount in token units - PC_DBT_DB.PROD.HEX_TO_BASE58(SUBSTRING(hex_data, 160+1, 64)) as mint, + {{ big_endian_hex_to_decimal("SUBSTR(hex_data,224+1,16)") }} as amount, -- fee amount in token units + {{ hex_to_base58("SUBSTR(hex_data, 160+1, 64)") }} as mint, hex_data, tx_id FROM hex_cte diff --git a/models/staging/jupiter/fact_jupiter_perps_txs.sql b/models/staging/jupiter/fact_jupiter_perps_txs.sql index 4c3b8894..72d74fee 100644 --- a/models/staging/jupiter/fact_jupiter_perps_txs.sql +++ b/models/staging/jupiter/fact_jupiter_perps_txs.sql @@ -10,7 +10,7 @@ with hex_cte as ( SELECT block_timestamp, tx_id, - PC_DBT_DB.PROD.BASE58_TO_HEX(f.value:data) as hex_data, + {{ base58_to_hex("f.value:data") }} as hex_data, f.value:data as base58_data FROM solana_flipside.core.fact_events, LATERAL FLATTEN(input => get_path(inner_instruction, 'instructions')) AS f @@ -30,11 +30,11 @@ with hex_cte as ( block_timestamp, tx_id, 'inc' as type, - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,582+1,16))/1e6 as size_usd, -- position size fee - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,680+1,16))/1e6 as fees_usd, --open fee - PC_DBT_DB.PROD.HEX_TO_BASE58(SUBSTRING(hex_data,454+1,64)) as owner, -- owner/trader address - PC_DBT_DB.PROD.HEX_TO_BASE58(SUBSTRING(hex_data,243,64)) as mint, - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,630+1,16))/1e6 as price, + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,582+1,16)") }}/1e6 as size_usd, -- position size fee + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,680+1,16)") }}/1e6 as fees_usd, --open fee + {{ hex_to_base58("SUBSTRING(hex_data,454+1,64)") }} as owner, -- owner/trader address + {{ hex_to_base58("SUBSTRING(hex_data,243,64)") }} as mint, + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,630+1,16)") }}/1e6 as price, hex_data FROM hex_cte WHERE SUBSTRING(hex_data,17,16) = 'f5715534d6bb9984' -- IncreasePosition @@ -45,15 +45,15 @@ with hex_cte as ( block_timestamp, tx_id, 'dec' as type, - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data, 584+1,16))/1e6 as size_usd, --open fee + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data, 584+1,16)") }}/1e6 as size_usd, --open fee case when substring(hex_data,1+651,1) = 1 - then PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,1+668,16)) / 1e6 - else PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,1+652,16)) / 1e6 + then {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,1+668,16)") }}/1e6 + else {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,1+652,16)") }}/1e6 end as fee_usd, --close fee, has an optional param priceSlippage before it so we need this case when. - PC_DBT_DB.PROD.HEX_TO_BASE58(SUBSTRING(hex_data,456+1,64)) as owner, -- owner/trader address - PC_DBT_DB.PROD.HEX_TO_BASE58(SUBSTRING(hex_data,243,64)) as mint, + {{ hex_to_base58("SUBSTRING(hex_data,456+1,64)") }} as owner, -- owner/trader address + {{ hex_to_base58("SUBSTRING(hex_data,243,64)") }} as mint, -- Price calculation with dynamic offset - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL( + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,619+1,16)") }}/1e6 as price, SUBSTRING( hex_data, 619 -- Base offset to price @@ -75,19 +75,20 @@ with hex_cte as ( block_timestamp, tx_id, 'liq' as type, - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,1+354,16)) / 1e6 as size_usd, --close fee - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,1+564,16)) / 1e6 as fee_usd, --close fee - PC_DBT_DB.PROD.HEX_TO_BASE58(SUBSTRING(hex_data,1+388,64)) as owner, -- owner/trader address - PC_DBT_DB.PROD.HEX_TO_BASE58(SUBSTRING(hex_data,291,64)) as mint, + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,1+354,16)") }}/1e6 as size_usd, --close fee + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,1+564,16)") }}/1e6 as fee_usd, --close fee + {{ hex_to_base58("SUBSTRING(hex_data,1+388,64)") }} as owner, -- owner/trader address + {{ hex_to_base58("SUBSTRING(hex_data,291,64)") }} as mint, case when block_timestamp >= date('2023-10-16 07:33:16.000') - THEN PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,549,16))/1e6 + THEN {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,549,16)") }}/1e6 ELSE - PC_DBT_DB.PROD.BIG_ENDIAN_HEX_TO_DECIMAL(SUBSTRING(hex_data,531,16))/1e6 + {{ big_endian_hex_to_decimal("SUBSTRING(hex_data,531,16)") }}/1e6 END as price, hex_data FROM hex_cte WHERE substring(hex_data,1+16,16) IN ('68452084d423bf2f', '806547a880485654') --LiquidatePosition, LiquidateFullPosition ) + SELECT block_timestamp, tx_id, @@ -100,3 +101,4 @@ SELECT price, hex_data FROM agg + diff --git a/models/staging/maple/__maple__sources.yml b/models/staging/maple/__maple__sources.yml new file mode 100644 index 00000000..2c0fb058 --- /dev/null +++ b/models/staging/maple/__maple__sources.yml @@ -0,0 +1,24 @@ +sources: + - name: ETHEREUM_FLIPSIDE + schema: core + database: ethereum_flipside + tables: + - name: ez_decoded_event_logs + - name: fact_event_logs + - name: fact_blocks + - name: fact_decoded_event_logs + - name: ez_token_transfers + + - name: ETHEREUM_FLIPSIDE + schema: price + database: ethereum_flipside + tables: + - name: ez_prices_hourly + + - name: PROD_LANDING + schema: prod_landing + database: landing_database + tables: + - name: raw_maple_otc_by_day + - name: raw_maple_solana_by_day + - name: raw_maple_dim_pools diff --git a/models/staging/maple/dim_maple_dates.sql b/models/staging/maple/dim_maple_dates.sql new file mode 100644 index 00000000..5350b551 --- /dev/null +++ b/models/staging/maple/dim_maple_dates.sql @@ -0,0 +1,13 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +SELECT + distinct date_trunc('day', block_timestamp) as date, + MAX(block_number) as last_block +FROM {{ source('ETHEREUM_FLIPSIDE', 'fact_blocks') }} +WHERE block_timestamp >= DATE('2022-12-12') +GROUP BY date_trunc('day', block_timestamp) \ No newline at end of file diff --git a/models/staging/maple/dim_maple_pools.sql b/models/staging/maple/dim_maple_pools.sql new file mode 100644 index 00000000..bf364b45 --- /dev/null +++ b/models/staging/maple/dim_maple_pools.sql @@ -0,0 +1,32 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + + +-- Creates a table consisting of each Maple Pool with its ID, name, activation block, Loan Managers, etc. +-- For Pools that were migrated from V1->V2, also includes the V1 contract address so we can merge all historical data for those Pools +-- Each Pool is denominated in a single asset, and we store that asset's on-chain decimal precision here (e.g. WETH is 18, USDC is 6) + +-- Source: + +with + max_extraction as ( + select max(extraction_date) as max_date + from {{ source("PROD_LANDING", "raw_maple_dim_pools") }} + ) +select + value:pool_id::string as pool_id, + value:pool_name::string as pool_name, + value:loan_manager::string as loan_manager, + value:open_term_loan_manager::string as open_term_loan_manager, + value:v1_pool_id::string as v1_pool_id, + value:asset::string as asset, + value:precision::int as precision, + value:block_activated::int as block_activated +from + {{ source("PROD_LANDING", "raw_maple_dim_pools") }}, + lateral flatten(input => parse_json(source_json)) +where extraction_date = (select max_date from max_extraction) \ No newline at end of file diff --git a/models/staging/maple/dim_maple_v2_pool_deposit_pools.sql b/models/staging/maple/dim_maple_v2_pool_deposit_pools.sql new file mode 100644 index 00000000..5a4793f8 --- /dev/null +++ b/models/staging/maple/dim_maple_v2_pool_deposit_pools.sql @@ -0,0 +1,41 @@ +{{ + config( + materialized = 'incremental', + unique_key = ['pool_address'], + snowflake_warehouse = 'MAPLE', + ) +}} + + +with agg as( + SELECT + distinct({{ hex_string_to_evm_address("SUBSTR(topics[1], 27, 40)::string") }}) as pool_address + FROM + {{source('ETHEREUM_FLIPSIDE', 'fact_event_logs')}} + where topics[0] = lower('0xf55841bdafd5af17a3183b609d4042325203ab6eb4747e435c6a044b6eb27b05') + {% if is_incremental() %} + and block_timestamp > (select dateadd('day', -1, max(last_updated)) from {{this}}) + {% endif %} + + UNION ALL + + SELECT + distinct({{ hex_string_to_evm_address("SUBSTR(data, 27, 40)::string") }}) as pool_address + FROM + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} + WHERE topics[0] = '0x0f91882b50d9330af0b1d4998e6af7f2eaee90ce7e77ea54fea089af166d021d' + AND contract_address in ( + lower('0x1Bb73D6384ae73DA2101a4556a42eaB82803Ef3d') + , lower('0x2c630CC5F1988e840C5D7F3bD5a43844CcdCf363') + , lower('0x1146691782c089bCF0B19aCb8620943a35eebD12') + , lower('0x8228719eA6dCc79b77d663F13af98684a637d3A0') + , lower('0x7F0d63e2250bC99f48985B183AF0c9a66BbC8ac3') + ) + {% if is_incremental() %} + and block_timestamp > (select dateadd('day', -1, max(last_updated)) from {{this}}) + {% endif %} +) +SELECT + sysdate() as last_updated, + * +FROM agg \ No newline at end of file diff --git a/models/staging/maple/dim_maple_withdrawal_managers.sql b/models/staging/maple/dim_maple_withdrawal_managers.sql new file mode 100644 index 00000000..42f29beb --- /dev/null +++ b/models/staging/maple/dim_maple_withdrawal_managers.sql @@ -0,0 +1,30 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + + +SELECT + * +FROM + ( VALUES + ('0x8a665131e796203a5232527fac441480e02fbb7f', 'High Yield Secured Lending', '0xc39a5a616f0ad1ff45077fa2de3f79ab8eb8b8b9'), + ('0x1bc47a0dd0fdab96e9ef982fdf1f34dc6207cfe3', 'Syrup USDC', '0x80ac24aa929eaf5013f6436cda2a7ba190f5cc0b'), + ('0x86ebdf902d800f2a82038290b6dbb2a5ee29eb8c', 'Syrup USDT', '0x356b8d89c1e1239cbbb9de4815c39a1474d5ba7d'), + ('0xf18066db3a9590c401e1841598ad90663b4c6d23', 'Secured Lending', '0xc1dd3f011290f212227170f0d02f511ebf57e433'), + ('0xb7ae6358aba6e7a60c7b921b8cbb3fddb3ee9060', 'Secured Lending', '0xc1dd3f011290f212227170f0d02f511ebf57e433'), + ('0xeb7b1e9c750190214cdfbbaf0abe398a5e47d230', 'High Yield Corporate USDC', '0x6174a27160f4d7885db4ffed1c0b5fbd66c87f3a'), + ('0x58a534945f357aa0d2fb56b8bdf7dfa1073bd7a1', 'High Yield Corporate WETH', '0xccbc525ed9d85ad8325b7b6c4c6a79f5566dea3b'), + ('0x447dcea1d616f792645ed6e71bc32955a0dbcbaa', 'Maple Cash USDC1', '0xfe119e9c24ab79f1bdd5dd884b86ceea2ee75d92'), + ('0x1146691782c089bcf0b19acb8620943a35eebd12', 'Maple Cash USDC1', '0xfe119e9c24ab79f1bdd5dd884b86ceea2ee75d92'), + ('0xf0a66f70064ad3198abb35aae26b1eeeaea62c4b', 'Maple Cash USDT1', '0xf05681a33a9adf14076990789a89ab3da3f6b536'), + ('0x515f77fc8e1473591a89181a2cf6cd0aaf3f932d', 'AQRU Receivables Financing', '0xe9d33286f0e37f517b1204aa6da085564414996d'), + ('0x8228719ea6dcc79b77d663f13af98684a637d3a0', 'AQRU Receivables Financing', '0xe9d33286f0e37f517b1204aa6da085564414996d'), + ('0x1b56856eb74bb1aa9e9f1997386ddb28def532ee', 'M11 Credit USDC1', '0x00e0c1ea2085e30e5233e98cfa940ca8cbb1b0b7'), + ('0x7ed195a0ae212d265511b0978af577f59876c9bb', 'M11 Credit USDC2', '0xd3cd37a7299b963bbc69592e5ba933388f70dc88'), + ('0x7f0d63e2250bc99f48985b183af0c9a66bbc8ac3', 'M11 Credit USDC3', '0xd2b01f8327eeca47829efc731f1a89c6d07e6b92'), + ('0x1bb73d6384ae73da2101a4556a42eab82803ef3d', 'M11 Credit WETH', '0xfff9a1caf78b2e5b0a49355a8637ea78b43fb6c3'), + ('0xd8f8bd488ba6ddf2a710f6c357a884fd1706981a', 'Orthogonal Credit USDC1', '0x79400a2c9a5e2431419cac98bf46893c86e8bdd7') +) as managers (withdrawal_manager, pool_name, pool_id) \ No newline at end of file diff --git a/models/staging/maple/fact_maple_Pool_evt_Claim.sql b/models/staging/maple/fact_maple_Pool_evt_Claim.sql new file mode 100644 index 00000000..1e5e9048 --- /dev/null +++ b/models/staging/maple/fact_maple_Pool_evt_Claim.sql @@ -0,0 +1,35 @@ +{{ + config( + materialized='incremental', + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse='MAPLE' + ) +}} + +with pools as ( + SELECT + decoded_log:pool as pool_address, + decoded_log:liquidityAsset as pool_liquidity_asset + FROM + {{ source('ETHEREUM_FLIPSIDE', 'fact_decoded_event_logs') }} + WHERE CONTRACT_ADDRESS = lower('0x2Cd79F7f8b38B9c0D80EA6B230441841A31537eC') + AND event_name = 'PoolCreated' +) + +select + l.block_timestamp, + l.tx_hash, + l.event_index, + l.contract_address, + l.topics, + l.data, + p.pool_liquidity_asset, + PC_DBT_DB.PROD.HEX_TO_INT(substr(l.data, 0, 64+2)) as interest, + PC_DBT_DB.PROD.HEX_TO_INT(substr(l.data, 64+3, 64)) as principal, + PC_DBT_DB.PROD.HEX_TO_INT(substr(l.data, 128+3, 64)) as fee +from {{ source('ETHEREUM_FLIPSIDE', 'fact_event_logs') }} l +join pools p on p.pool_address = l.contract_address +where topics[0] = lower('0x21280d282ce6aa29c649fd1825373d7c77892fac3f1958fd98d5ca52dd82a197') +{% if is_incremental() %} + AND l.block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_accounting_updates.sql b/models/staging/maple/fact_maple_accounting_updates.sql new file mode 100644 index 00000000..8b8ea923 --- /dev/null +++ b/models/staging/maple/fact_maple_accounting_updates.sql @@ -0,0 +1,50 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH ftl_accounting AS ( + SELECT + f.block_timestamp AS date, + f.tx_hash, + f.block, + p.pool_name, + p.asset, + f.accountedInterest_ / POWER(10, p.precision) AS ftl_accounted, + f.issuanceRate_ / POWER(10, (30 + p.precision)) AS ftl_issuance_rate, + NULL AS otl_accounted, + NULL AS otl_issuance_rate, + 'FTL Accounting Update' AS description + FROM {{ ref('fact_maple_v2_LoanManager_IssuanceParamsUpdated') }} f + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.loan_manager = f.contract_address + WHERE date(date) != DATE('2022-12-12') +), + +otl_accounting AS ( + SELECT + o.block_timestamp AS date, + o.tx_hash, + o.block, + p.pool_name, + p.asset, + NULL AS ftl_accounted, + NULL AS ftl_issuance_rate, + o.accountedInterest_ / POWER(10, p.precision) AS otl_accounted, + o.issuanceRate_ / POWER(10, (27 + p.precision)) AS otl_issuance_rate, + 'OTL Accounting Update' AS description + FROM {{ ref('fact_maple_v2_OpenTermLoanManager_AccountingStateUpdated') }} o + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.open_term_loan_manager = o.contract_address +), + +all_accounting AS ( + SELECT * FROM ftl_accounting + UNION ALL + SELECT * FROM otl_accounting +) + +SELECT * FROM all_accounting +WHERE pool_name IS NOT NULL + AND date(date) != DATE('2022-12-11') -- Exclude events from migration day +ORDER BY date \ No newline at end of file diff --git a/models/staging/maple/fact_maple_agg_tvl.sql b/models/staging/maple/fact_maple_agg_tvl.sql new file mode 100644 index 00000000..9c4cd76e --- /dev/null +++ b/models/staging/maple/fact_maple_agg_tvl.sql @@ -0,0 +1,38 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} +WITH agg_tvl AS ( + SELECT + date, + pool_name, + asset, + outstanding_usd as tvl, + outstanding_usd as tvl_native, + null as outstanding_supply + FROM {{ ref('fact_maple_v1_tvl') }} + UNION ALL + SELECT + date, + pool_name, + asset, + tvl, + tvl_native, + outstanding as outstanding_supply + FROM {{ ref('fact_maple_v2_tvl') }} +) + +SELECT + date, + pool_name, + asset, + sum(tvl) as tvl, + sum(tvl_native) as tvl_native, + sum(outstanding_supply) as outstanding_supply +FROM agg_tvl +GROUP BY 1, 2, 3 +-- WHERE +-- pool_name NOT IN ('Orthogonal Credit USDC1') +ORDER BY date DESC, pool_name \ No newline at end of file diff --git a/models/staging/maple/fact_maple_all_events.sql b/models/staging/maple/fact_maple_all_events.sql new file mode 100644 index 00000000..94ed9b8b --- /dev/null +++ b/models/staging/maple/fact_maple_all_events.sql @@ -0,0 +1,283 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH deposits AS ( + SELECT + date, + tx_hash, + block, + 'Deposit' as description, + pool_name, + asset, + amount, + shares, + NULL as interest, + NULL as principal, + NULL as ftl_outstanding, + NULL as ftl_accounted, + NULL as ftl_issuance_rate, + NULL as ftl_domain_start, + NULL as otl_outstanding, + NULL as otl_accounted, + NULL as otl_issuance_rate, + NULL as otl_domain_start + FROM {{ ref('fact_maple_deposits') }} +), + +withdrawals AS ( + SELECT + date, + tx_hash, + block, + 'Withdrawal' as description, + pool_name, + asset, + amount * -1 as amount, + shares * -1 as shares, + NULL as interest, + NULL as principal, + NULL as ftl_outstanding, + NULL as ftl_accounted, + NULL as ftl_issuance_rate, + NULL as ftl_domain_start, + NULL as otl_outstanding, + NULL as otl_accounted, + NULL as otl_issuance_rate, + NULL as otl_domain_start + FROM {{ ref('fact_maple_withdrawals') }} +), + +payments AS ( + SELECT + date, + tx_hash, + block, + description, + pool_name, + asset, + NULL as amount, + NULL as shares, + net_interest_paid as interest, + NULL as principal, + NULL as ftl_outstanding, + NULL as ftl_accounted, + NULL as ftl_issuance_rate, + NULL as ftl_domain_start, + NULL as otl_outstanding, + NULL as otl_accounted, + NULL as otl_issuance_rate, + NULL as otl_domain_start + FROM {{ ref('fact_maple_payments') }} +), + +accounting AS ( + SELECT + date, + tx_hash, + block, + description, + pool_name, + asset, + NULL as amount, + NULL as shares, + NULL as interest, + NULL as principal, + NULL as ftl_outstanding, + ftl_accounted, + ftl_issuance_rate, + CASE WHEN description = 'FTL Accounting Update' THEN date ELSE NULL END AS ftl_domain_start, + NULL as otl_outstanding, + otl_accounted, + otl_issuance_rate, + CASE WHEN description = 'OTL Accounting Update' THEN date ELSE NULL END AS otl_domain_start + FROM {{ ref('fact_maple_accounting_updates') }} +), + +outstanding AS ( + SELECT + date, + tx_hash, + block, + description, + pool_name, + asset, + NULL as amount, + NULL as shares, + NULL as interest, + delta as principal, + CASE WHEN description = 'FTL Outstanding Update' THEN principal_out ELSE NULL END AS ftl_outstanding, + NULL as ftl_accounted, + NULL as ftl_issuance_rate, + NULL as ftl_domain_start, + CASE WHEN description = 'OTL Outstanding Update' THEN principal_out ELSE NULL END AS otl_outstanding, + NULL as otl_accounted, + NULL as otl_issuance_rate, + NULL as otl_domain_start + FROM {{ ref('fact_maple_principal_updates') }} +), + +outstanding_accounting AS ( + SELECT + outs.date, + outs.tx_hash, + outs.block, + CASE + WHEN outs.principal > 0 AND outs.description = 'FTL Outstanding Update' THEN 'FTL Issuance' + WHEN outs.principal > 0 AND outs.description = 'OTL Outstanding Update' THEN 'OTL Issuance' + WHEN outs.principal < 0 AND outs.description = 'FTL Outstanding Update' THEN 'FTL Paid Down' + WHEN outs.principal < 0 AND outs.description = 'OTL Outstanding Update' THEN 'OTL Paid Down' + WHEN outs.principal = 0 AND outs.description = 'FTL Outstanding Update' THEN 'FTL Refinance' + WHEN outs.principal = 0 AND outs.description = 'OTL Outstanding Update' THEN 'OTL Refinance' + ELSE 'Accounting Update' + END AS description, + outs.pool_name, + outs.asset, + outs.amount, + outs.shares, + CASE + WHEN outs.principal = 0 AND outs.description = 'FTL Outstanding Update' THEN NULL + ELSE p.interest + END AS interest, + outs.principal, + outs.ftl_outstanding, + a.ftl_accounted, + a.ftl_issuance_rate, + a.ftl_domain_start, + outs.otl_outstanding, + a.otl_accounted, + a.otl_issuance_rate, + a.otl_domain_start + FROM outstanding outs + LEFT JOIN accounting a ON a.block = outs.block AND a.pool_name = outs.pool_name + LEFT JOIN payments p ON p.block = outs.block AND p.pool_name = outs.pool_name +), + +interest_payments AS ( + SELECT + p.date, + p.tx_hash, + p.block, + p.description, + p.pool_name, + p.asset, + p.amount, + p.shares, + p.interest, + outs.principal, + outs.ftl_outstanding, + a.ftl_accounted, + a.ftl_issuance_rate, + a.ftl_domain_start, + outs.otl_outstanding, + a.otl_accounted, + a.otl_issuance_rate, + a.otl_domain_start + FROM payments p + LEFT JOIN outstanding outs ON p.block = outs.block AND p.pool_name = outs.pool_name + LEFT JOIN accounting a ON a.block = p.block AND a.pool_name = p.pool_name + WHERE outs.principal IS NULL +), + +joined AS ( + SELECT * FROM outstanding_accounting + UNION ALL + SELECT * FROM interest_payments +), + +all_events AS ( + SELECT * FROM deposits + UNION ALL + SELECT * FROM withdrawals + UNION ALL + SELECT * FROM joined +), + +all_events_migration AS ( + SELECT + date, + tx_hash, + block, + description, + pool_name, + asset, + CASE + WHEN block = 16164991 AND pool_name = 'M11 Credit USDC1' THEN 8765965.068493 + WHEN block = 16164991 AND pool_name = 'Orthogonal Credit USDC1' THEN 16944059.896081 + WHEN block = 16164991 AND pool_name = 'M11 Credit USDC2' THEN 1.24615 + 615006.54 + WHEN (block = 16178669 OR block = 16178695 OR block = 16178705) AND pool_name = 'M11 Credit USDC2' THEN 0 + WHEN block = 16164991 AND pool_name = 'M11 Credit WETH' THEN 1395.6268730806437 + 64.07 + WHEN (block = 16178815 OR block = 16178824 OR block = 16178830) AND pool_name = 'M11 Credit WETH' THEN 0 + ELSE amount + END AS amount, + shares, + interest, + principal, + ftl_outstanding, + ftl_accounted, + ftl_issuance_rate, + ftl_domain_start, + otl_outstanding, + otl_accounted, + otl_issuance_rate, + otl_domain_start + FROM all_events +) + +SELECT + date, + tx_hash, + block, + description, + pool_name, + asset, + COALESCE(amount, 0) as amount, + COALESCE(shares, 0) as shares, + COALESCE(interest, 0) as interest, + COALESCE(principal, 0) as principal, + COALESCE(LAST_VALUE(ftl_outstanding) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as ftl_outstanding, + COALESCE(LAST_VALUE(ftl_accounted) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as ftl_accounted, + COALESCE(LAST_VALUE(ftl_issuance_rate) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as ftl_issuance_rate, + COALESCE(LAST_VALUE(DATE_PART(EPOCH_SECONDS, ftl_domain_start)) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as ftl_domain_start, + COALESCE(LAST_VALUE(otl_outstanding) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as otl_outstanding, + COALESCE(LAST_VALUE(otl_accounted) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as otl_accounted, + COALESCE(LAST_VALUE(otl_issuance_rate) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as otl_issuance_rate, + COALESCE(LAST_VALUE(DATE_PART(EPOCH_SECONDS, otl_domain_start)) IGNORE NULLS OVER ( + PARTITION BY pool_name + ORDER BY block + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ), 0) as otl_domain_start +FROM all_events_migration +WHERE pool_name IS NOT NULL +ORDER BY block DESC \ No newline at end of file diff --git a/models/staging/maple/fact_maple_deposits.sql b/models/staging/maple/fact_maple_deposits.sql new file mode 100644 index 00000000..3a61370e --- /dev/null +++ b/models/staging/maple/fact_maple_deposits.sql @@ -0,0 +1,20 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + + +SELECT + d.block_timestamp AS date, + d.tx_hash, + d.block, + p.pool_name, + p.asset, + d.owner_ AS lender_id, + d.shares_ / POWER(10, p.precision) AS shares, + d.assets_ / POWER(10, p.precision) AS amount, + 'Deposit' AS description +FROM {{ ref('fact_maple_v2_Pool_Deposit') }} d +LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.pool_id = d.contract_address \ No newline at end of file diff --git a/models/staging/maple/fact_maple_fees.sql b/models/staging/maple/fact_maple_fees.sql new file mode 100644 index 00000000..82393210 --- /dev/null +++ b/models/staging/maple/fact_maple_fees.sql @@ -0,0 +1,30 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE' + ) +}} + +SELECT + DATE(block_timestamp) AS date, + asset, + pool_name, + net_interest AS net_interest_usd, + net_interest_native AS net_interest_native, + platform_fees_usd, + platform_fees_native, + delegate_fees_usd, + delegate_fees_native +FROM {{ ref('fact_maple_interest_v2') }} +UNION ALL +SELECT + DATE(block_timestamp) AS date, + asset, + pool_name, + interest_to_lps_usd AS net_interest_usd, + interest_to_lps_native AS net_interest_native, + NULL as platform_fees_usd, + NULL as platform_fees_native, + NULL as delegate_fees_usd, + NULL as delegate_fees_native +FROM {{ ref('fact_maple_interest_v1') }} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_interest_v1.sql b/models/staging/maple/fact_maple_interest_v1.sql new file mode 100644 index 00000000..ce68dc76 --- /dev/null +++ b/models/staging/maple/fact_maple_interest_v1.sql @@ -0,0 +1,32 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +with eth_prices as ( + select * from {{ source('ETHEREUM_FLIPSIDE', 'ez_prices_hourly') }} + where is_native = True +) +select + block_timestamp, + tx_hash, + contract_address, + pools.pool_name, + pools.asset, + CASE + -- For the WETH Pools, convert to USD using the current price of ETH + WHEN contract_address = '0x1a066b0109545455bc771e49e6edef6303cb0a93' OR contract_address = '0xa1fe1b5fc23c2dab0c28d4cc09021014f30be8f1' + THEN interest / POW(10, 18) * p.price + ELSE interest / POW(10, 6) + END AS interest_to_lps_usd, + CASE + WHEN contract_address = '0x1a066b0109545455bc771e49e6edef6303cb0a93' OR contract_address = '0xa1fe1b5fc23c2dab0c28d4cc09021014f30be8f1' + THEN interest / POW(10, 18) + ELSE interest / POW(10, 6) + END AS interest_to_lps_native +FROM + {{ ref('fact_maple_Pool_evt_Claim') }} c +LEFT JOIN eth_prices p on p.hour = date_trunc('hour', c.block_timestamp) +LEFT JOIN {{ ref('dim_maple_pools') }} pools ON c.contract_address = pools.v1_pool_id \ No newline at end of file diff --git a/models/staging/maple/fact_maple_interest_v2.sql b/models/staging/maple/fact_maple_interest_v2.sql new file mode 100644 index 00000000..8cdcf7e2 --- /dev/null +++ b/models/staging/maple/fact_maple_interest_v2.sql @@ -0,0 +1,90 @@ +{{ + config( + materialized = 'table', + snowflake_warehouse = 'MAPLE' + ) +}} + +with eth_prices as ( + select * from {{source('ETHEREUM_FLIPSIDE', 'ez_prices_hourly')}} + where is_native = True +) +, ftlm_interest as ( + select + block_timestamp, + tx_hash, + contract_address, + pools.pool_name, + pools.asset, + CASE WHEN + contract_address = '0x373bdcf21f6a939713d5de94096ffdb24a406391' + THEN netinterest_ / POW(10,18) * p.price + ELSE netinterest_ / POW(10, 6) + END AS net_interest, + CASE WHEN + contract_address = '0x373bdcf21f6a939713d5de94096ffdb24a406391' + THEN netinterest_ / POW(10,18) + ELSE netinterest_ / POW(10, 6) + END AS net_interest_native, + NULL as platform_fees_usd, + NULL as platform_fees_native, + NULL as delegate_fees_usd, + NULL as delegate_fees_native + from {{ ref('fact_maple_v2_LoanManager_FundsDistributed') }} f + left join eth_prices p on p.hour = date_trunc('hour', f.block_timestamp) + LEFT JOIN {{ ref('dim_maple_pools') }} pools ON f.contract_address = pools.loan_manager +) + +-- OTLM (448 rows) +, otlm_interest as ( + select + block_timestamp, + contract_address, + tx_hash, + pools.pool_name, + pools.asset, + CASE + WHEN contract_address in ('0x373bdcf21f6a939713d5de94096ffdb24a406391', '0xe3aac29001c769fafcef0df072ca396e310ed13b') + THEN netinterest_ / POW(10,18) * p.price + ELSE netinterest_ / POW(10, 6) + END AS net_interest_usd, + CASE + WHEN contract_address in ('0x373bdcf21f6a939713d5de94096ffdb24a406391', '0xe3aac29001c769fafcef0df072ca396e310ed13b') + THEN netinterest_ / POW(10,18) + ELSE netinterest_ / POW(10, 6) + END AS net_interest_native, + CASE + WHEN contract_address in ('0x373bdcf21f6a939713d5de94096ffdb24a406391', '0xe3aac29001c769fafcef0df072ca396e310ed13b') + THEN (platformManagementFee_ + platformServiceFee_) / POW(10, 18) * p.price + ELSE (platformManagementFee_ + platformServiceFee_) / POW(10, 6) + END AS platform_fees_usd, + CASE + WHEN contract_address in ('0x373bdcf21f6a939713d5de94096ffdb24a406391', '0xe3aac29001c769fafcef0df072ca396e310ed13b') + THEN (platformManagementFee_ + platformServiceFee_) / POW(10, 18) + ELSE (platformManagementFee_ + platformServiceFee_) / POW(10, 6) + END AS platform_fees_native, + CASE + WHEN contract_address in ('0x373bdcf21f6a939713d5de94096ffdb24a406391', '0xe3aac29001c769fafcef0df072ca396e310ed13b') + THEN (delegateManagementFee_ + delegateServiceFee_) / POW(10, 18) * p.price + ELSE (delegateManagementFee_ + delegateServiceFee_) / POW(10, 6) + END AS delegate_fees_usd, + CASE + WHEN contract_address in ('0x373bdcf21f6a939713d5de94096ffdb24a406391', '0xe3aac29001c769fafcef0df072ca396e310ed13b') + THEN (delegateManagementFee_ + delegateServiceFee_) / POW(10, 18) + ELSE (delegateManagementFee_ + delegateServiceFee_) / POW(10, 6) + END AS delegate_fees_native + from {{ ref('fact_maple_v2_OpenTermLoanManager_ClaimedFundsDistributed') }} f + left join eth_prices p on p.hour = date_trunc('hour', f.block_timestamp) + LEFT JOIN {{ ref('dim_maple_pools') }} pools ON f.contract_address = pools.open_term_loan_manager +) +, agg as( + SELECT + * + FROM ftlm_interest + UNION ALL + SELECT + * + FROM otlm_interest +) +SELECT * FROM agg +WHERE pool_name is not null \ No newline at end of file diff --git a/models/staging/maple/fact_maple_offchain_data.sql b/models/staging/maple/fact_maple_offchain_data.sql new file mode 100644 index 00000000..6f480449 --- /dev/null +++ b/models/staging/maple/fact_maple_offchain_data.sql @@ -0,0 +1,374 @@ +-- fact_maple_offchain_data.sql +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + + +WITH prices AS ( + SELECT + date(hour) as date, + symbol, + avg(price) as price + FROM + {{ source('ETHEREUM_FLIPSIDE', 'ez_prices_hourly') }} + WHERE + symbol in ('WBTC', 'INJ', 'SOL', 'STETH') + or is_native = true + GROUP BY 1, 2 +) -- Blue Chip Secured: Collateral +, bc_collateral AS ( + SELECT + d.date, + btc.symbol as asset, + d.bc_collat_btc as collateral_amount_native, + d.bc_collat_btc * btc.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices btc using (date) + WHERE btc.symbol = 'WBTC' + UNION ALL + SELECT + d.date, + steth.symbol as asset, + d.bc_collat_steth as collateral_amount_native, + d.bc_collat_steth * steth.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices steth using (date) + WHERE steth.symbol = 'STETH' +), + +bc_totals AS ( + SELECT + date, + asset, + 'Secured Lending' as pool_name, + sum(collateral_amount_native) as collat_native, + sum(collateral_usd) as collat_usd + FROM bc_collateral + GROUP BY 1, 2 +) + +-- High Yield Secured: Collateral +, hy_collateral_by_token AS ( + SELECT + d.date, + sol.symbol as asset, + d.hy_collat_sol as collateral_amount_native, + d.hy_collat_sol * sol.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices sol using (date) + WHERE sol.symbol = 'SOL' + UNION ALL + SELECT + d.date, + btc.symbol as asset, + d.hy_collat_btc as collateral_amount_native, + d.hy_collat_btc * btc.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices btc using (date) + WHERE btc.symbol = 'WBTC' + UNION ALL + SELECT + d.date, + eth.symbol as asset, + d.hy_collat_eth as collateral_amount_native, + d.hy_collat_eth * eth.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices eth using (date) + WHERE eth.symbol = 'ETH' + UNION ALL + SELECT + d.date, + ftm.symbol as asset, + d.hy_collat_ftm as collateral_amount_native, + d.hy_collat_ftm * ftm.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices ftm using (date) + WHERE ftm.symbol = 'FTM' +), + +hy_totals AS ( + SELECT + date, + asset, + 'High Yield Secured Lending' as pool_name, + sum(collateral_amount_native) as collat_native, + sum(collateral_usd) as collat_usd + FROM hy_collateral_by_token + GROUP BY 1, 2 +), + +-- Syrup USDC: Collateral +syrup_usdc_collateral_by_token AS ( + SELECT + d.date, + sol.symbol as asset, + d.syrup_usdc_collat_sol as collateral_amount_native, + d.syrup_usdc_collat_sol * sol.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices sol using (date) + WHERE sol.symbol = 'SOL' + UNION ALL + SELECT + d.date, + btc.symbol as asset, + d.syrup_usdc_collat_btc as collateral_amount_native, + d.syrup_usdc_collat_btc * btc.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices btc using (date) + WHERE btc.symbol = 'WBTC' + UNION ALL + SELECT + d.date, + eth.symbol as asset, + d.syrup_usdc_collat_eth as collateral_amount_native, + d.syrup_usdc_collat_eth * eth.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices eth using (date) + WHERE eth.symbol = 'ETH' + UNION ALL + SELECT + d.date, + 'PT-USDC' as asset, + d.syrup_usdc_collat_pt as collateral_amount_native, + d.syrup_usdc_collat_pt * 0.986 as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + UNION ALL + SELECT + d.date, + 'ORCA-LP' as asset, + d.syrup_usdc_collat_orca as collateral_amount_native, + d.syrup_usdc_collat_orca * 1 as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d +), + +syrup_usdc_totals AS ( + SELECT + date, + asset, + 'Syrup USDC' as pool_name, + sum(collateral_amount_native) as collat_native, + sum(collateral_usd) as collat_usd + FROM syrup_usdc_collateral_by_token + GROUP BY 1, 2 +), + +-- Syrup USDT: Collateral +syrup_usdt_collateral_by_token AS ( + SELECT + d.date, + sol.symbol as asset, + d.syrup_usdt_collat_sol as collateral_amount_native, + d.syrup_usdt_collat_sol * sol.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices sol using (date) + WHERE sol.symbol = 'SOL' + UNION ALL + SELECT + d.date, + btc.symbol as asset, + d.syrup_usdt_collat_btc as collateral_amount_native, + d.syrup_usdt_collat_btc * btc.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices btc using (date) + WHERE btc.symbol = 'WBTC' + UNION ALL + SELECT + d.date, + eth.symbol as asset, + d.syrup_usdt_collat_eth as collateral_amount_native, + d.syrup_usdt_collat_eth * eth.price as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices eth using (date) + WHERE eth.symbol = 'ETH' + UNION ALL + SELECT + d.date, + 'PT-USDT' as asset, + d.syrup_usdt_collat_pt as collateral_amount_native, + d.syrup_usdt_collat_pt * 0.95 as collateral_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d +), + +syrup_usdt_totals AS ( + SELECT + date, + asset, + 'Syrup USDT' as pool_name, + sum(collateral_amount_native) as collat_native, + sum(collateral_usd) as collat_usd + FROM syrup_usdt_collateral_by_token + GROUP BY 1, 2 +), + +-- Altcoin Lending: Deposits, Loans, and Collateral +alt_lending_by_token AS ( + -- SOL positions + SELECT + DATE(TO_TIMESTAMP_NTZ(d.timestamp - 86399)) as date, + sol.symbol as asset, + 'loan' as position_type, + d.alt_loans_sol as amount_native, + d.alt_loans_sol * sol.price as amount_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices sol using (date) + WHERE sol.symbol = 'SOL' + UNION ALL + SELECT + DATE(TO_TIMESTAMP_NTZ(d.timestamp - 86399)) as date, + sol.symbol as asset, + 'deposit' as position_type, + d.alt_deposits_sol as amount_native, + d.alt_deposits_sol * sol.price as amount_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices sol using (date) + WHERE sol.symbol = 'SOL' + + UNION ALL + -- BTC positions + SELECT + DATE(TO_TIMESTAMP_NTZ(d.timestamp - 86399)) as date, + btc.symbol as asset, + 'loan' as position_type, + d.alt_loans_btc as amount_native, + d.alt_loans_btc * btc.price as amount_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices btc using (date) + WHERE btc.symbol = 'WBTC' + UNION ALL + SELECT + DATE(TO_TIMESTAMP_NTZ(d.timestamp - 86399)) as date, + btc.symbol as asset, + 'deposit' as position_type, + d.alt_deposits_btc as amount_native, + d.alt_deposits_btc * btc.price as amount_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices btc using (date) + WHERE btc.symbol = 'WBTC' + UNION ALL + SELECT + DATE(TO_TIMESTAMP_NTZ(d.timestamp - 86399)) as date, + btc.symbol as asset, + 'collateral' as position_type, + d.alt_collat_btc as amount_native, + d.alt_collat_btc * btc.price as amount_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices btc using (date) + WHERE btc.symbol = 'WBTC' + + UNION ALL + -- INJ positions + SELECT + DATE(TO_TIMESTAMP_NTZ(d.timestamp - 86399)) as date, + inj.symbol as asset, + 'loan' as position_type, + d.alt_loans_inj as amount_native, + d.alt_loans_inj * inj.price as amount_usd + FROM + {{ ref('fact_maple_otc_by_day') }} d + LEFT JOIN prices inj using (date) + WHERE inj.symbol = 'INJ' +), + +alt_totals AS ( + SELECT + date, + asset, + 'Altcoin Lending' as pool_name, + sum(case when position_type = 'loan' then amount_usd else 0 end) as outstanding, + sum(case when position_type = 'loan' then amount_native else 0 end) as outstanding_native, + sum(case when position_type in ('deposit', 'collateral') or position_type = 'loan' and asset = 'INJ' then amount_usd else 0 end) as total_assets, + sum(case when position_type in ('deposit', 'collateral') or position_type = 'loan' and asset = 'INJ' then amount_native else 0 end) as total_assets_native, + sum(case when position_type = 'collateral' then amount_usd else 0 end) as collat_usd, + sum(case when position_type = 'collateral' then amount_native else 0 end) as collat_native, + sum(case when position_type in ('deposit', 'collateral') or position_type = 'loan' and asset = 'INJ' then amount_usd else 0 end) as tvl, + sum(case when position_type in ('deposit', 'collateral') or position_type = 'loan' and asset = 'INJ' then amount_native else 0 end) as tvl_native + FROM + alt_lending_by_token + WHERE + date IS NOT NULL + AND date <= CURRENT_DATE + GROUP BY 1, 2 +) +-- Solana Cash Management +, solana AS ( + SELECT + DATE(TO_TIMESTAMP_NTZ(timestamp)) as date, + 'USDC' as asset, -- Source: https://maple.finance/news/maple-brings-cash-management-solution-to-solana + 'Maple Solana' as pool_name, + outstanding_usd as outstanding, + outstanding_usd as outstanding_native, + outstanding_usd as total_assets, + outstanding_usd as total_assets_native, + 0 as collat_native, + 0 as collat_usd, + outstanding_usd as tvl, + outstanding_usd as tvl_native + FROM + {{ ref('fact_maple_solana_by_day') }} + WHERE + DATE(TO_TIMESTAMP_NTZ(timestamp)) <= CURRENT_DATE +) + +SELECT + date, + pool_name, + asset, + collat_native, + collat_usd as collateral, + NULL as outstanding, + NULL as outstanding_native, + NULL as total_assets, + NULL as total_assets_native, + NULL as tvl, + NULL as tvl_native +FROM bc_totals +UNION ALL +SELECT date, pool_name, asset, collat_native, collat_usd as collateral, NULL as outstanding, NULL as outstanding_native, NULL as total_assets, NULL as total_assets_native, NULL as tvl, NULL as tvl_native +FROM hy_totals +UNION ALL +SELECT date, pool_name, asset, collat_native, collat_usd as collateral, NULL as outstanding, NULL as outstanding_native, NULL as total_assets, NULL as total_assets_native, NULL as tvl, NULL as tvl_native +FROM syrup_usdc_totals +UNION ALL +SELECT date, pool_name, asset, collat_native, collat_usd as collateral, NULL as outstanding, NULL as outstanding_native, NULL as total_assets, NULL as total_assets_native, NULL as tvl, NULL as tvl_native +FROM syrup_usdt_totals +UNION ALL +-- Below, do total_assets and tvl fit the same structure by asset and pool, native, etc as collateral? +SELECT + date, + pool_name, + asset, + collat_native, + collat_usd as collateral, + outstanding, + outstanding_native, + total_assets, + total_assets_native, + tvl, + tvl_native +FROM alt_totals +UNION ALL +SELECT date, pool_name, asset, collat_native, collat_usd as collateral, outstanding, outstanding_native, total_assets, total_assets_native, tvl, tvl_native +FROM solana \ No newline at end of file diff --git a/models/staging/maple/fact_maple_onchain_revenue.sql b/models/staging/maple/fact_maple_onchain_revenue.sql new file mode 100644 index 00000000..bb1248a9 --- /dev/null +++ b/models/staging/maple/fact_maple_onchain_revenue.sql @@ -0,0 +1,30 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +SELECT + block_timestamp, + tx_hash, + contract_address, + p.symbol as token, + to_address, + raw_amount_precise / pow(10, p.decimals) as revenue_native, + raw_amount_precise / pow(10, p.decimals) * p.price as revenue_usd +FROM + {{ source('ETHEREUM_FLIPSIDE', 'ez_token_transfers') }} t +LEFT JOIN {{ source('ETHEREUM_FLIPSIDE', 'ez_prices_hourly') }} p + ON date_trunc('hour', block_timestamp) = p.hour + AND p.token_address = t.contract_address +WHERE t.to_address = lower('0xa9466eabd096449d650d5aeb0dd3da6f52fd0b19') +OR t.to_address = lower('0xd15b90ff80aa7e13fc69cd7ccd9fef654495e36c') +OR t.to_address = lower('0x687f2C038e2DAA38F8dAc0c5941d7B5E58bd8CA6') +OR t.to_address = lower('0x94b8dcbe4c7841B54170925b67918a6312154C9c') +OR t.to_address = lower('0x8c6a34E2b9CeceE4a1fce672ba37e611B1AECebB') +OR (t.to_address = lower('0x0984af3FcB364c1f30337F9aB453f876e7Ff6D0B') + AND t.from_address NOT IN (lower('0xd15b90ff80aa7e13fc69cd7ccd9fef654495e36c'), lower('0x6D7F31cDbE68e947fAFaCad005f6495eDA04cB12'))) +OR t.to_address = lower('0x7263d9Cd36d5cAe7B681906c0e29a4A94C0938A9') +OR (t.to_address = lower('0x6D7F31cDbE68e947fAFaCad005f6495eDA04cB12') + AND t.from_address = lower('0xdC9b93A8A336fe5dc9DB97616eA2118000d70fc0')) \ No newline at end of file diff --git a/models/staging/maple/fact_maple_otc_by_day.sql b/models/staging/maple/fact_maple_otc_by_day.sql new file mode 100644 index 00000000..05deaf9a --- /dev/null +++ b/models/staging/maple/fact_maple_otc_by_day.sql @@ -0,0 +1,40 @@ +{{ + config( + materialized="table", + snowflake_warehouse="MAPLE", + ) +}} +with + max_extraction as ( + select max(extraction_date) as max_date + from {{ source("PROD_LANDING", "raw_maple_otc_by_day") }} + ) +select + value:date::date as date, + value:timestamp::int as timestamp, + value:alt_collat_btc::float as alt_collat_btc, + value:alt_deposits_btc::float as alt_deposits_btc, + value:alt_deposits_sol::float as alt_deposits_sol, + value:alt_loans_btc::float as alt_loans_btc, + value:alt_loans_inj::float as alt_loans_inj, + value:alt_loans_sol::float as alt_loans_sol, + value:bc_collat_btc::float as bc_collat_btc, + value:bc_collat_steth::float as bc_collat_steth, + value:hy_collat_btc::float as hy_collat_btc, + value:hy_collat_eth::float as hy_collat_eth, + value:hy_collat_sol::float as hy_collat_sol, + value:hy_collat_ftm::float as hy_collat_ftm, + value:syrup_usdc_collat_btc::float as syrup_usdc_collat_btc, + value:syrup_usdc_collat_eth::float as syrup_usdc_collat_eth, + value:syrup_usdc_collat_orca::float as syrup_usdc_collat_orca, + value:syrup_usdc_collat_pt::float as syrup_usdc_collat_pt, + value:syrup_usdc_collat_sol::float as syrup_usdc_collat_sol, + value:syrup_usdt_collat_btc::float as syrup_usdt_collat_btc, + value:syrup_usdt_collat_eth::float as syrup_usdt_collat_eth, + value:syrup_usdt_collat_pt::float as syrup_usdt_collat_pt, + value:syrup_usdt_collat_sol::float as syrup_usdt_collat_sol, + value:otc_revenue::float as otc_revenue +from + {{ source("PROD_LANDING", "raw_maple_otc_by_day") }}, + lateral flatten(input => parse_json(source_json)) +where extraction_date = (select max_date from max_extraction) diff --git a/models/staging/maple/fact_maple_payments.sql b/models/staging/maple/fact_maple_payments.sql new file mode 100644 index 00000000..90074043 --- /dev/null +++ b/models/staging/maple/fact_maple_payments.sql @@ -0,0 +1,44 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH ftl_payments AS ( + SELECT + f.block_timestamp AS date, + f.tx_hash, + f.block, + p.pool_name, + p.asset, + f.principal_ / POWER(10, p.precision) AS principal_paid, + f.netInterest_ / POWER(10, p.precision) AS net_interest_paid, + 'FTL Interest Payment' AS description + FROM {{ ref('fact_maple_v2_LoanManager_FundsDistributed') }} f + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.loan_manager = f.contract_address +), + +otl_payments AS ( + SELECT + o.block_timestamp AS date, + o.tx_hash, + o.block, + p.pool_name, + p.asset, + o.principal_ / POWER(10, p.precision) AS principal_paid, + (o.netInterest_ - o.platformManagementFee_ - o.delegateManagementFee_) / POWER(10, p.precision) AS net_interest_paid, + 'OTL Interest Payment' AS description + FROM {{ ref('fact_maple_v2_OpenTermLoanManager_ClaimedFundsDistributed') }} o + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.open_term_loan_manager = o.contract_address +), + +all_payments AS ( + SELECT * FROM ftl_payments + UNION ALL + SELECT * FROM otl_payments +) + +SELECT * FROM all_payments +WHERE pool_name IS NOT NULL +ORDER BY date \ No newline at end of file diff --git a/models/staging/maple/fact_maple_pool_state_daily.sql b/models/staging/maple/fact_maple_pool_state_daily.sql new file mode 100644 index 00000000..b915f813 --- /dev/null +++ b/models/staging/maple/fact_maple_pool_state_daily.sql @@ -0,0 +1,134 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH dates AS ( + SELECT * FROM {{ ref('dim_maple_dates') }} +), + +pool_ids AS ( + SELECT DISTINCT pool_id, asset, pool_name, block_activated + FROM {{ ref('dim_maple_pools') }} + WHERE pool_name NOT IN ('Celsius WETH Pool', 'Alameda Research - USDC', 'BlockTower Capital - USDC01') +), + +dates_pools AS ( + SELECT + d.date, + -- For the UNIX timestamp, we want the LAST timestamp of the day, so add 86399 seconds + DATE_PART('epoch', d.date) + 86399 as last_ts, + d.last_block, + p.pool_name, + p.asset + FROM dates d + CROSS JOIN pool_ids p + -- Only add Pool to each date if it had already been activated + WHERE d.last_block >= p.block_activated +), + +-- From the table of all Pool states, pull only the latest each day, by Pool +latest_states_only AS ( + SELECT + *, + ROW_NUMBER() OVER (PARTITION BY pool_name, date ORDER BY date DESC) as row_num + FROM {{ ref('fact_maple_pool_state_history') }} +), + +-- Fill in Pool values for every day where there was not an update +states AS ( + SELECT + d.date, d.last_ts, d.last_block, d.pool_name, d.asset, + LAST_VALUE(s.assets) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as assets, + LAST_VALUE(s.pool_shares) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as pool_shares, + LAST_VALUE(s.outstanding) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as outstanding, + LAST_VALUE(s.accounted) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as accounted, + LAST_VALUE(s.ftl_issuance_rate) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as ftl_issuance_rate, + LAST_VALUE(s.ftl_domain_start) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as ftl_domain_start, + LAST_VALUE(s.otl_issuance_rate) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as otl_issuance_rate, + LAST_VALUE(s.otl_domain_start) IGNORE NULLS OVER ( + PARTITION BY d.pool_name + ORDER BY d.date + ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW + ) as otl_domain_start + FROM dates_pools d + LEFT JOIN latest_states_only s + ON s.date = d.date AND s.pool_name = d.pool_name AND s.row_num = 1 +), + +-- Prep some columns like accrued interest that will be needed for total assets +prep_states AS ( + SELECT + date, last_ts, last_block, pool_name, asset, assets, pool_shares, outstanding, + -- Balance is the amount of assets in the Pool that is currently earning interest; outstanding + idle cash + assets + outstanding as balance, + accounted, + -- Annualize interest from both FTL and OTL Loan Managers; using 365 days/year and 86400 seconds/day + ftl_issuance_rate, + ftl_issuance_rate * 86400 * 365 as ftl_ann_interest, + ftl_domain_start, + (last_ts - ftl_domain_start) * ftl_issuance_rate as ftl_accrued, + otl_issuance_rate, + otl_issuance_rate * 86400 * 365 as otl_ann_interest, + otl_domain_start, + (last_ts - otl_domain_start) * otl_issuance_rate as otl_accrued + FROM states +), + +-- Calculate total assets, exchange rate, current net APY, and utilization +all_states AS ( + SELECT + *, + ftl_accrued + otl_accrued as total_accrued, + assets + outstanding + accounted + (ftl_accrued + otl_accrued) as total_assets, + (assets + outstanding + accounted + (ftl_accrued + otl_accrued)) / NULLIF(pool_shares, 0) as exch_rate, + CASE + WHEN pool_name = 'High Yield Secured Lending' THEN (ftl_ann_interest + otl_ann_interest) / NULLIF(balance, 0) + 0.08 + WHEN pool_name = 'Syrup USDC' OR pool_name = 'Syrup USDT' THEN (ftl_ann_interest + otl_ann_interest) / NULLIF(balance, 0) + 0.066 + ELSE (ftl_ann_interest + otl_ann_interest) / NULLIF(balance, 0) + END AS spot_apy, + outstanding / NULLIF(balance, 0) as utilization + FROM prep_states +), + +-- Add trailing averages; e.g. 30 day average APY, lifetime APY, etc. +all_states_trailing AS ( + SELECT + *, + AVG(CASE WHEN spot_apy > 0 THEN spot_apy ELSE NULL END) OVER (PARTITION BY pool_name ORDER BY date ROWS BETWEEN 29 PRECEDING AND CURRENT ROW) as apy_trailing_30, + AVG(CASE WHEN spot_apy > 0 THEN spot_apy ELSE NULL END) OVER (PARTITION BY pool_name ORDER BY date) as lifetime_apy + FROM all_states +) + +SELECT * FROM all_states_trailing +WHERE pool_name IN ('Syrup USDC', 'Syrup USDT', 'Secured Lending', 'High Yield Secured Lending', 'Maple Cash USDC1', 'High Yield Corporate USDC', 'AQRU Receivables Financing') diff --git a/models/staging/maple/fact_maple_pool_state_history.sql b/models/staging/maple/fact_maple_pool_state_history.sql new file mode 100644 index 00000000..d82076a5 --- /dev/null +++ b/models/staging/maple/fact_maple_pool_state_history.sql @@ -0,0 +1,34 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +SELECT + date(date) as date, + tx_hash, + block, + description, + pool_name, + asset, + amount, + shares, + interest, + principal, + -- Assets (idle cash) will be a running sum of the amount column; by Pool + -- Basically the cash in the Pool is always changing as deposits come in, loans are issued, payments are made, etc. + -- Subtract principal since if principal decreased, that's an increase to Pool cash + SUM(amount + interest - principal) OVER (PARTITION BY pool_name ORDER BY block) as assets, + SUM(shares) OVER (PARTITION BY pool_name ORDER BY block) as pool_shares, + ftl_outstanding + otl_outstanding as outstanding, + ftl_accounted + otl_accounted as accounted, + ftl_outstanding, + ftl_accounted, + ftl_issuance_rate, + ftl_domain_start, + otl_outstanding, + otl_accounted, + otl_issuance_rate, + otl_domain_start +FROM {{ ref('fact_maple_all_events') }} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_principal_updates.sql b/models/staging/maple/fact_maple_principal_updates.sql new file mode 100644 index 00000000..6ca05bc0 --- /dev/null +++ b/models/staging/maple/fact_maple_principal_updates.sql @@ -0,0 +1,70 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH ftl_principal AS ( + with all_ftl as ( + SELECT + f.block_timestamp AS date, + f.tx_hash, + f.block, + p.pool_name, + p.asset, + f.principalOut_ / POWER(10, p.precision) AS principal_out, + 'FTL Outstanding Update' AS description + FROM {{ ref('fact_maple_v2_LoanManager_PrincipalOutUpdated') }} f + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.loan_manager = f.contract_address + WHERE date(date) > DATE('2022-12-12') + + UNION ALL + SELECT + date, tx_hash, block, pool_name, asset, principal_out, description + FROM + {{ ref('fact_maple_v2_loan_manager_manual_entries') }} + ) + , intermediate as ( + SELECT + date, + tx_hash, + block, + pool_name, + principal_out, + principal_out - LAG( principal_out, 1, 0) OVER (PARTITION BY pool_name ORDER BY date) AS delta, + description, + asset + FROM all_ftl + ) + SELECT * FROM intermediate + UNION ALL + select + * + FROM {{ ref('fact_maple_v2_loan_manager_manual_entries') }} + ORDER BY date(date) ASC, delta DESC +), + +otl_principal AS ( + SELECT + o.block_timestamp AS date, + o.tx_hash, + o.block, + p.pool_name, + o.principalOut_ / POWER(10, p.precision) AS principal_out, + o.principalOut_ / POWER(10, p.precision) - LAG(o.principalOut_ / POWER(10, p.precision), 1, 0) OVER (PARTITION BY pool_name ORDER BY date) AS delta, + 'OTL Outstanding Update' AS description, + p.asset + FROM {{ ref('fact_maple_v2_OpenTermLoanManager_PrincipalOutUpdated') }} o + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.open_term_loan_manager = o.contract_address +) + +, all_outs as( + SELECT * FROM ftl_principal + UNION ALL + SELECT * FROM otl_principal +) +SELECT * FROM all_outs +WHERE pool_name IS NOT NULL + AND date(date) != DATE('2022-12-11') -- Exclude events from migration day +ORDER BY date \ No newline at end of file diff --git a/models/staging/maple/fact_maple_revenue.sql b/models/staging/maple/fact_maple_revenue.sql new file mode 100644 index 00000000..59c8cb7e --- /dev/null +++ b/models/staging/maple/fact_maple_revenue.sql @@ -0,0 +1,25 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +SELECT + date(to_timestamp_ntz(timestamp - 83699)) as date, + 'USD' as token, + SUM(otc_revenue) as revenue, + SUM(otc_revenue) as revenue_native +FROM + {{ ref('fact_maple_otc_by_day') }} d +GROUP BY 1 + +UNION ALL +SELECT + date(block_timestamp) as date, + token, + SUM(revenue_usd) as revenue, + SUM(revenue_native) as revenue_native +FROM + {{ ref('fact_maple_onchain_revenue') }} +GROUP BY 1, 2 diff --git a/models/staging/maple/fact_maple_solana_by_day.sql b/models/staging/maple/fact_maple_solana_by_day.sql new file mode 100644 index 00000000..cd180f93 --- /dev/null +++ b/models/staging/maple/fact_maple_solana_by_day.sql @@ -0,0 +1,21 @@ +{{ + config( + materialized="table", + snowflake_warehouse="MAPLE", + ) +}} + +with + max_extraction as ( + select max(extraction_date) as max_date + from {{ source("PROD_LANDING", "raw_maple_solana_by_day") }} + ) +select + value:parsed_date::date as date, + value:timestamp::int as timestamp, + value:pool_name::string as pool_name, + value:outstanding_usd::number as outstanding_usd +from + {{ source("PROD_LANDING", "raw_maple_solana_by_day") }}, + lateral flatten(input => parse_json(source_json)) +where extraction_date = (select max_date from max_extraction) diff --git a/models/staging/maple/fact_maple_token_incentives.sql b/models/staging/maple/fact_maple_token_incentives.sql new file mode 100644 index 00000000..d403bd29 --- /dev/null +++ b/models/staging/maple/fact_maple_token_incentives.sql @@ -0,0 +1,36 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE' + ) +}} + +with rewards_contracts as ( + SELECT + decoded_log:mplRewards as rewards_contract_address + FROM + {{ source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs') }} + where + event_name = 'MplRewardsCreated' +) +, mpl_prices as ( + SELECT + hour, + price, + decimals, + token_address, + symbol + FROM + {{ source('ETHEREUM_FLIPSIDE', 'ez_prices_hourly') }} + WHERE token_address = lower('0x33349b282065b0284d756f0577fb39c158f935e6') +) +SELECT + block_timestamp, + symbol as token, + decoded_log:reward * POWER(10, p.decimals) as incentive_native, + decoded_log:reward * p.price / POWER(10, p.decimals) as incentive_usd +FROM + {{ source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs') }} l +LEFT JOIN mpl_prices p ON p.hour = DATE_TRUNC('hour', l.block_timestamp) +WHERE contract_address in (SELECT rewards_contract_address FROM rewards_contracts) +AND event_name = 'RewardPaid' \ No newline at end of file diff --git a/models/staging/maple/fact_maple_tokenholder_count.sql b/models/staging/maple/fact_maple_tokenholder_count.sql new file mode 100644 index 00000000..bf8a85e1 --- /dev/null +++ b/models/staging/maple/fact_maple_tokenholder_count.sql @@ -0,0 +1,8 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE' + ) +}} + +{{ token_holders('ethereum', '0x33349b282065b0284d756f0577fb39c158f935e6', '2021-04-20') }} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_treasury.sql b/models/staging/maple/fact_maple_treasury.sql new file mode 100644 index 00000000..8550e262 --- /dev/null +++ b/models/staging/maple/fact_maple_treasury.sql @@ -0,0 +1,16 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE' + ) +}} + +{{ get_treasury_balance( + chain='ethereum', + addresses=[ + '0xa9466eabd096449d650d5aeb0dd3da6f52fd0b19', + '0xd6d4Bcde6c816F17889f1Dd3000aF0261B03a196' + ], + earliest_date='2020-09-12' + ) +}} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v1_FixedTermLoan_evt_PaymentMade.sql b/models/staging/maple/fact_maple_v1_FixedTermLoan_evt_PaymentMade.sql new file mode 100644 index 00000000..381fe869 --- /dev/null +++ b/models/staging/maple/fact_maple_v1_FixedTermLoan_evt_PaymentMade.sql @@ -0,0 +1,54 @@ +{{ + config( + materialized='incremental', + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse='MAPLE', + ) +}} + +-- All rows present +with fixed_term_loan_pools as ( + select + distinct decoded_log:instance_::string as instance_address + from + {{ source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs') }} + where + event_name= 'InstanceDeployed' + and lower(contract_address) = lower('0x36a7350309B2Eb30F3B908aB0154851B5ED81db0') +) + +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:principalPaid_::number as principalPaid_ + , decoded_log:interestPaid_::number as interestPaid_ + , decoded_log:fees_::string as fees_ +from + {{ source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs') }} +where + event_name = 'PaymentMade' + and contract_address in (select instance_address from fixed_term_loan_pools) +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} + +union all + +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(data, 3, 64)) as principalPaid_ + , PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(data, 64+3, 64)) as interestPaid_ + , PC_DBT_DB.PROD.HEX_TO_INT(SUBSTR(data, 128+3, 64)) as fees_ +from {{ source('ETHEREUM_FLIPSIDE', 'fact_event_logs') }} +where topics[0] = lower('0xcf358e925a8e033c6db877f18d10df6f21cd04ef165537bad5fc814eb23af960') +and contract_address in (select instance_address from fixed_term_loan_pools) +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v1_Loan_evt_PaymentMade.sql b/models/staging/maple/fact_maple_v1_Loan_evt_PaymentMade.sql new file mode 100644 index 00000000..66df46f7 --- /dev/null +++ b/models/staging/maple/fact_maple_v1_Loan_evt_PaymentMade.sql @@ -0,0 +1,30 @@ +{{ + config( + materialized='incremental', + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse='MAPLE', + ) +}} + +-- outputs 9 rows less than expected +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:interestPaid::number as interestPaid + , decoded_log:latePayment::string as latePayment + , decoded_log:nextPaymentDue::number as nextPaymentDue + , decoded_log:paymentsRemaining::number as paymentsRemaining + , decoded_log:principalOwed::number as principalOwed + , decoded_log:principalPaid::number as principalPaid + , decoded_log:totalPaid::number as totalPaid +from + {{ source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs') }} +where + event_name = 'PaymentMade' + and decoded_log:interestPaid is not null +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v1_Pool_LoanFunded.sql b/models/staging/maple/fact_maple_v1_Pool_LoanFunded.sql new file mode 100644 index 00000000..b6796d12 --- /dev/null +++ b/models/staging/maple/fact_maple_v1_Pool_LoanFunded.sql @@ -0,0 +1,25 @@ +{{ + config( + materialized='incremental', + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse='MAPLE', + ) +}} + +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:amountFunded::number as amountFunded + , decoded_log:debtLocker::string as debtLocker + , decoded_log:loan::string as loan +from + {{ source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs') }} +where + event_name = 'LoanFunded' + and decoded_log:debtLocker is not null +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v1_loans.sql b/models/staging/maple/fact_maple_v1_loans.sql new file mode 100644 index 00000000..0a8dd191 --- /dev/null +++ b/models/staging/maple/fact_maple_v1_loans.sql @@ -0,0 +1,18 @@ +{{ config(materialized='table', snowflake_warehouse='MAPLE') }} + + +SELECT + DATE_TRUNC('day', block_timestamp) as date, + loan as loan_id, + pools.pool_name, + pools.pool_id, + pools.asset, + pools.precision, + amountFunded / POWER(10, pools.precision) as amount_funded +FROM + {{ ref('fact_maple_v1_Pool_LoanFunded') }} +LEFT JOIN + {{ ref('dim_maple_pools') }} pools ON pools.v1_pool_id = contract_address +WHERE +-- -- Exclude the migration Loans that were funded to bring Pools from V1->V2; December 11 2022 + DATE_TRUNC('day', block_timestamp) < DATE('2022-12-11') \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v1_repayments.sql b/models/staging/maple/fact_maple_v1_repayments.sql new file mode 100644 index 00000000..f03be6d5 --- /dev/null +++ b/models/staging/maple/fact_maple_v1_repayments.sql @@ -0,0 +1,51 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH loans AS ( + SELECT DISTINCT + l.loan_id, + l.pool_name, + l.pool_id, + l.asset, + l.precision + FROM {{ ref('fact_maple_v1_loans') }} l +), + +v1_payments AS ( + SELECT + DATE_TRUNC('day', block_timestamp) as date, + contract_address as loan_id, + loans.pool_name, + loans.pool_id, + loans.asset, + interestPaid / POWER(10, loans.precision) as gross_interest_paid, + principalPaid / POWER(10, loans.precision) as principal_paid + FROM + {{ ref('fact_maple_v1_Loan_evt_PaymentMade') }} + LEFT JOIN + loans ON loans.loan_id = contract_address +), + +payments AS ( + SELECT + DATE_TRUNC('day', block_timestamp) as date, + contract_address as loan_id, + loans.pool_name, + loans.pool_id, + loans.asset, + interestPaid_ / POWER(10, loans.precision) as gross_interest_paid, + principalPaid_ / POWER(10, loans.precision) as principal_paid + FROM + {{ ref('fact_maple_v1_FixedTermLoan_evt_PaymentMade') }} + LEFT JOIN + loans ON loans.loan_id = contract_address +) + +SELECT * FROM v1_payments +UNION ALL +-- For the newer versions of Loan, filter out anything after the V2 migration +SELECT * FROM payments \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v1_tvl.sql b/models/staging/maple/fact_maple_v1_tvl.sql new file mode 100644 index 00000000..815b3e5b --- /dev/null +++ b/models/staging/maple/fact_maple_v1_tvl.sql @@ -0,0 +1,84 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH daily_orig AS ( + SELECT + date, + pool_name, + asset, + SUM(amount_funded) as daily_funded + FROM {{ ref('fact_maple_v1_loans') }} + GROUP BY 1,2,3 +), + +daily_pays AS ( + SELECT + date, + pool_name, + asset, + SUM(principal_paid) as daily_repaid + FROM {{ ref('fact_maple_v1_repayments') }} + WHERE principal_paid > 0 + GROUP BY 1,2,3 +), + +dates AS ( + SELECT + distinct date_trunc('day', block_timestamp) as date + FROM {{ source('ETHEREUM_FLIPSIDE', 'fact_blocks') }} + WHERE block_timestamp >= (SELECT MIN(date) FROM {{ ref('fact_maple_v1_loans') }}) + AND block_timestamp < DATE('2022-12-11') +), + +pools AS (SELECT DISTINCT pool_name FROM {{ ref('fact_maple_v1_loans') }}), + +dates_pools AS ( + SELECT + d.date, + p.pool_name + FROM dates d + CROSS JOIN pools p +), + +prep_daily AS ( + SELECT + d.date, + d.pool_name, + coalesce(daily_orig.asset, daily_pays.asset) as asset, + COALESCE(daily_orig.daily_funded, 0) as daily_funded, + COALESCE(daily_pays.daily_repaid, 0) as daily_repaid + FROM dates_pools d + LEFT JOIN daily_orig ON daily_orig.date = d.date AND daily_orig.pool_name = d.pool_name + LEFT JOIN daily_pays ON daily_pays.date = d.date AND daily_pays.pool_name = d.pool_name +), + +daily AS ( + SELECT + *, + daily_funded - daily_repaid as change + FROM prep_daily +), + +final AS ( + SELECT + *, + SUM(change) OVER (PARTITION BY pool_name ORDER BY date) as outstanding + FROM daily +) + +SELECT + date, + pool_name, + asset, + daily_funded, + daily_repaid, + CASE + WHEN pool_name = 'M11 Credit WETH' OR pool_name = 'Celsius WETH Pool' + THEN outstanding * (SELECT price FROM {{ source('ETHEREUM_FLIPSIDE', 'ez_prices_hourly') }} WHERE is_native = TRUE ORDER BY hour DESC LIMIT 1) + ELSE outstanding + END as outstanding_usd +FROM final \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_LoanManager_FundsDistributed.sql b/models/staging/maple/fact_maple_v2_LoanManager_FundsDistributed.sql new file mode 100644 index 00000000..a299c4ae --- /dev/null +++ b/models/staging/maple/fact_maple_v2_LoanManager_FundsDistributed.sql @@ -0,0 +1,25 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:loan_::string as loan_ + , decoded_log:principal_::number as principal_ + , decoded_log:netInterest_::number as netInterest_ +from + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'FundsDistributed' + and decoded_log:loan_ is not null +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_LoanManager_IssuanceParamsUpdated.sql b/models/staging/maple/fact_maple_v2_LoanManager_IssuanceParamsUpdated.sql new file mode 100644 index 00000000..3467d5e4 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_LoanManager_IssuanceParamsUpdated.sql @@ -0,0 +1,25 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +select + block_timestamp, + tx_hash, + event_index, + block_number as block, + contract_address, + decoded_log:accountedInterest_::number as accountedInterest_, + decoded_log:domainEnd_::number as domainEnd_, + decoded_log:issuanceRate_::float as issuanceRate_ +from + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'IssuanceParamsUpdated' + and decoded_log:domainEnd_ is not null +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_LoanManager_PrincipalOutUpdated.sql b/models/staging/maple/fact_maple_v2_LoanManager_PrincipalOutUpdated.sql new file mode 100644 index 00000000..341a8df9 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_LoanManager_PrincipalOutUpdated.sql @@ -0,0 +1,38 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +-- 224 rows as expected +with loan_manager_addresses as ( + SELECT + decoded_log:loanManager_::string as lm_address + FROM + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} + where + event_name = 'PoolConfigured' +) +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:principalOut_::number as principalOut_ +from + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'PrincipalOutUpdated' + and (contract_address in ( + SELECT + lm_address + from + loan_manager_addresses + ) + or contract_address = '0x7a459f1fb7d257fc62e23aaa8b802e061cec68d7') +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_OpenTermLoanManager_AccountingStateUpdated.sql b/models/staging/maple/fact_maple_v2_OpenTermLoanManager_AccountingStateUpdated.sql new file mode 100644 index 00000000..2fff40ff --- /dev/null +++ b/models/staging/maple/fact_maple_v2_OpenTermLoanManager_AccountingStateUpdated.sql @@ -0,0 +1,24 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +-- 521 rows as expected +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:accountedInterest_::number as accountedInterest_ + , decoded_log:issuanceRate_::float as issuanceRate_ +from + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'AccountingStateUpdated' +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_OpenTermLoanManager_ClaimedFundsDistributed.sql b/models/staging/maple/fact_maple_v2_OpenTermLoanManager_ClaimedFundsDistributed.sql new file mode 100644 index 00000000..782b3446 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_OpenTermLoanManager_ClaimedFundsDistributed.sql @@ -0,0 +1,29 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:loan_::string as loan_ + , decoded_log:principal_::number as principal_ + , decoded_log:netInterest_::number as netInterest_ + , decoded_log:delegateManagementFee_::number as delegateManagementFee_ + , decoded_log:delegateServiceFee_::number as delegateServiceFee_ + , decoded_log:platformManagementFee_::number as platformManagementFee_ + , decoded_log:platformServiceFee_::number as platformServiceFee_ +from + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'ClaimedFundsDistributed' + and decoded_log:loan_ is not null +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_OpenTermLoanManager_PrincipalOutUpdated.sql b/models/staging/maple/fact_maple_v2_OpenTermLoanManager_PrincipalOutUpdated.sql new file mode 100644 index 00000000..da37e6c5 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_OpenTermLoanManager_PrincipalOutUpdated.sql @@ -0,0 +1,38 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +-- 380 rows expected, +with loan_manager_addresses as ( + SELECT + '0x' || SUBSTR(topics[1], 24+3, 40)::string as lm_address + FROM + {{source('ETHEREUM_FLIPSIDE', 'fact_event_logs')}} + where + topics[0] = '0x870b352f9e61b22ce039fe5f1976fa831c1e76b68d0f7b86965abb7fad3d8112' +) +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:principalOut_::number as principalOut_ +from + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'PrincipalOutUpdated' + and contract_address in ( + SELECT + lm_address + from + loan_manager_addresses + ) + and contract_address <> '0x7a459f1fb7d257fc62e23aaa8b802e061cec68d7' +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_Pool_Deposit.sql b/models/staging/maple/fact_maple_v2_Pool_Deposit.sql new file mode 100644 index 00000000..35178262 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_Pool_Deposit.sql @@ -0,0 +1,30 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +-- Works but off by 8 txs + +with pools as ( + SELECT * FROM {{ ref('dim_maple_v2_pool_deposit_pools') }} +) +SELECT + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:assets_::number as assets_ + , decoded_log:caller_::string as caller_ + , decoded_log:owner_::string as owner_ + , decoded_log:shares_::number as shares_ +FROM + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} l +join pools p on lower(p.pool_address) = lower(l.contract_address) +where event_name = 'Deposit' +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} diff --git a/models/staging/maple/fact_maple_v2_QueueWithdrawalManager_RequestProcessed.sql b/models/staging/maple/fact_maple_v2_QueueWithdrawalManager_RequestProcessed.sql new file mode 100644 index 00000000..7df3a9b8 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_QueueWithdrawalManager_RequestProcessed.sql @@ -0,0 +1,28 @@ +{{ + config( + materialized='incremental', + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse='MAPLE', + ) +}} + +-- exact number of rows +SELECT + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:assets::number as assets_ + , decoded_log:"owner"::string as owner_ + , decoded_log:requestId::string as requestId_ + , decoded_log:"shares"::number as shares_ +FROM + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'RequestProcessed' + and decoded_log:requestId is not null + and decoded_log:"owner" is not null +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_WithdrawalManager_WithdrawalProcessed.sql b/models/staging/maple/fact_maple_v2_WithdrawalManager_WithdrawalProcessed.sql new file mode 100644 index 00000000..ca4f5689 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_WithdrawalManager_WithdrawalProcessed.sql @@ -0,0 +1,25 @@ +{{ + config( + materialized="incremental", + unique_key= ['tx_hash', 'event_index'], + snowflake_warehouse="MAPLE", + ) +}} + +select + block_timestamp + , tx_hash + , event_index + , block_number as block + , contract_address + , decoded_log:account_::string as account_ + , decoded_log:assetsToWithdraw_::number as assetsToWithdraw_ + , decoded_log:sharesToRedeem_::number as sharesToRedeem_ +from + {{source('ETHEREUM_FLIPSIDE', 'ez_decoded_event_logs')}} +where + event_name = 'WithdrawalProcessed' + and decoded_log:assetsToWithdraw_ is not null +{% if is_incremental() %} + AND block_timestamp > (select dateadd('day', -1, max(block_timestamp)) from {{ this }}) +{% endif %} \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_loan_manager_manual_entries.sql b/models/staging/maple/fact_maple_v2_loan_manager_manual_entries.sql new file mode 100644 index 00000000..cb06d410 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_loan_manager_manual_entries.sql @@ -0,0 +1,14 @@ +{{ + config( + materialized = 'table', + snowflake_warehouse = 'MAPLE' + ) +}} + +SELECT * FROM ( + VALUES + ('2022-12-12 00:00', '0xc2500c5bf2112cc39f80d314941d33b15e88a852b8e9a7ac4f9e7d6abdf89aad', 16164991, 'Orthogonal Credit USDC1', 4000000, 0, 'FTL Outstanding Update', 'USDC'), + ('2022-12-12 00:00', '0xc2500c5bf2112cc39f80d314941d33b15e88a852b8e9a7ac4f9e7d6abdf89aad', 16164991, 'M11 Credit WETH', 22170, 21200, 'FTL Outstanding Update', 'WETH'), + ('2022-12-12 00:00', '0xc2500c5bf2112cc39f80d314941d33b15e88a852b8e9a7ac4f9e7d6abdf89aad', 16164991, 'M11 Credit USDC2', 38500000, 14999998.753850002, 'FTL Outstanding Update', 'USDC'), + ('2022-12-12 00:00', '0xc2500c5bf2112cc39f80d314941d33b15e88a852b8e9a7ac4f9e7d6abdf89aad', 16164991, 'M11 Credit USDC1', 7500000, 0, 'FTL Outstanding Update', 'USDC') +) AS t (DATE, TX_HASH, BLOCK, POOL_NAME, PRINCIPAL_OUT, DELTA, DESCRIPTION, ASSET) \ No newline at end of file diff --git a/models/staging/maple/fact_maple_v2_tvl.sql b/models/staging/maple/fact_maple_v2_tvl.sql new file mode 100644 index 00000000..07fa2281 --- /dev/null +++ b/models/staging/maple/fact_maple_v2_tvl.sql @@ -0,0 +1,79 @@ +-- fact_maple_tvl.sql +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + + +WITH onchain_pools AS ( + SELECT + date, + pool_name, + asset, + outstanding, + outstanding as outstanding_native, + assets as cash, + total_assets, + total_assets as total_assets_native + FROM {{ ref('fact_maple_pool_state_daily') }} +), + +offchain_data AS ( + SELECT + date, + pool_name, + asset, + NULL as total_assets, + NULL as total_assets_native, + collateral, + collat_native + FROM {{ ref('fact_maple_offchain_data') }} + WHERE pool_name <> ('Altcoin Lending') + UNION ALL + SELECT + date, + pool_name, + asset, + total_assets, + total_assets_native, + NULL as collateral, + NULL as collat_native + FROM {{ ref('fact_maple_offchain_data') }} + WHERE pool_name = ('Altcoin Lending') +), + +combined_data AS ( + SELECT + date, + pool_name, + asset, + coalesce(outstanding, 0) as outstanding, + coalesce(outstanding, 0) as outstanding_native, + coalesce(total_assets, 0) as tvl, + coalesce(total_assets, 0) as tvl_native + FROM + onchain_pools + + UNION ALL + + SELECT + date, + pool_name, + asset, + 0 as outstanding, + 0 as outstanding_native, + coalesce(collateral, 0) + coalesce(total_assets, 0) as tvl, + coalesce(collat_native, 0) + coalesce(total_assets_native, 0) as tvl_native + FROM + offchain_data +) + +SELECT * +FROM combined_data +WHERE +-- date > DATE('2023-03-01') +-- AND + date <= CURRENT_DATE +ORDER BY date DESC, pool_name \ No newline at end of file diff --git a/models/staging/maple/fact_maple_withdrawals.sql b/models/staging/maple/fact_maple_withdrawals.sql new file mode 100644 index 00000000..ab9fca7b --- /dev/null +++ b/models/staging/maple/fact_maple_withdrawals.sql @@ -0,0 +1,46 @@ +{{ + config( + materialized='table', + snowflake_warehouse='MAPLE', + ) +}} + +WITH cyclical_withdrawals AS ( + SELECT + w.block_timestamp AS date, + w.tx_hash, + w.block, + p.pool_name, + p.asset, + w.account_ AS lender_id, + w.sharesToRedeem_ / POWER(10, p.precision) AS shares, + w.assetsToWithdraw_ / POWER(10, p.precision) AS amount, + 'Withdrawal' AS description + FROM {{ ref('fact_maple_v2_WithdrawalManager_WithdrawalProcessed') }} w + LEFT JOIN {{ ref('dim_maple_withdrawal_managers') }} wm ON wm.withdrawal_manager = w.contract_address + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.pool_id = wm.pool_id +), + +queue_withdrawals AS ( + SELECT + w.block_timestamp AS date, + w.tx_hash, + w.block, + p.pool_name, + p.asset, + w.owner_ AS lender_id, + w.shares_ / POWER(10, p.precision) AS shares, + w.assets_ / POWER(10, p.precision) AS amount, + 'Withdrawal' AS description + FROM {{ ref('fact_maple_v2_QueueWithdrawalManager_RequestProcessed') }} w + LEFT JOIN {{ ref('dim_maple_withdrawal_managers') }} wm ON wm.withdrawal_manager = w.contract_address + LEFT JOIN {{ ref('dim_maple_pools') }} p ON p.pool_id = wm.pool_id +), + +all_withdrawals AS ( + SELECT * FROM cyclical_withdrawals + UNION ALL + SELECT * FROM queue_withdrawals +) + +SELECT * FROM all_withdrawals diff --git a/udfs/hex_string_to_evm_address_udf.sql b/udfs/hex_string_to_evm_address_udf.sql new file mode 100644 index 00000000..95130707 --- /dev/null +++ b/udfs/hex_string_to_evm_address_udf.sql @@ -0,0 +1,30 @@ +CREATE OR REPLACE FUNCTION PC_DBT_DB.PROD.HEX_STRING_TO_EVM_ADDRESS("HEX_STRING" VARCHAR(16777216)) +RETURNS VARCHAR(42) +LANGUAGE PYTHON +RUNTIME_VERSION = '3.8' +HANDLER = 'HEX_STRING_TO_EVM_ADDRESS' +AS ' +def HEX_STRING_TO_EVM_ADDRESS(hex_string): + """ + Converts a hex string to a blockchain address by prepending ''0x''. + + Args: + hex_string (str): The input hex string to convert + + Returns: + str: The blockchain address with ''0x'' prefix + + Example: + Input: "1234abcd" + Output: "0x1234abcd" + """ + # Handle null input + if hex_string is None: + return None + + # Remove any existing ''0x'' prefix to avoid duplication + hex_string = hex_string.lower().replace(''0x'', '''') + + # Return the formatted address + return f"0x{hex_string}" +';