diff --git a/data/silver__stablecoin_bridge_vault_seed.csv b/data/silver__stablecoin_bridge_vault_seed.csv new file mode 100644 index 00000000..b1485327 --- /dev/null +++ b/data/silver__stablecoin_bridge_vault_seed.csv @@ -0,0 +1,7 @@ +protocol,vault_owner,vault_token_address,vault_mint_address +debridge,2snHHreXbpJ7UwZxPe37gnUNf7Wx7wv6UKDSR2JckKuS,DYU4yerNMB48M8vJPGCgdhduosocF6HgYFtHfVrGJ9wt,EPjFWdd5AufqSSqeM2qN1xzybapC8G4wEGGkZwyTDt1v +debridge,2snHHreXbpJ7UwZxPe37gnUNf7Wx7wv6UKDSR2JckKuS,4bKrVpLePtKvq5YiSrxmZXsiNJ1kySbPVTqiSwF2QSba,USDSwr9ApdHk5bvJKMjzff41FfuX8bSxdKcR81vTwcA +debridge,2snHHreXbpJ7UwZxPe37gnUNf7Wx7wv6UKDSR2JckKuS,CcJLxdGZbQgJUAqsvMob6QikDT2o8Bc6hjmRxX14PGpy,Es9vMFrzaCERmJfrF4H2FYD4KCoNkY11McCe8BenwNYB +mayan,FzZ77TM8Ekcb6gyWPmcT9upWkAZKZc5xrYfuFu7pifPn,9xKVSmHrcotzz5W8Ez6w3g6h7kXQoxUri8pozRucpMhE,EPjFWdd5AufqSSqeM2qN1xzybapC8G4wEGGkZwyTDt1v +wormhole,GugU1tP7doLeTw9hQP51xRJyS8Da1fWxuiy2rVrnMD2m,AZnLiVRARbovELxrhJynFJTyp8irqmUURoyXBtyPWK6C,Es9vMFrzaCERmJfrF4H2FYD4KCoNkY11McCe8BenwNYB +wormhole,GugU1tP7doLeTw9hQP51xRJyS8Da1fWxuiy2rVrnMD2m,9EhGiXJFGG7NGneq76Mfu6LCvGxHKmeq4tQv9HD4iBxV,EPjFWdd5AufqSSqeM2qN1xzybapC8G4wEGGkZwyTDt1v \ No newline at end of file diff --git a/models/gold/defi/defi__dim_stablecoins.sql b/models/gold/defi/defi__dim_stablecoins.sql index c0990cd6..405412dc 100644 --- a/models/gold/defi/defi__dim_stablecoins.sql +++ b/models/gold/defi/defi__dim_stablecoins.sql @@ -35,8 +35,9 @@ FROM m ON s.token_address = m.token_address AND s.blockchain = m.blockchain --- WHERE --- m.is_verified --verified stablecoins only +WHERE + m.is_verified --verified stablecoins only + and m.blockchain = 'solana' {% if is_incremental() %} AND s.modified_timestamp > ( @@ -48,37 +49,7 @@ AND s.modified_timestamp > ( {% endif %} ), --- manual_stablecoins AS ( --- SELECT --- s.contract_address, --- UPPER( --- m.symbol --- ) AS symbol, --- m.name, --- m.decimals, --- m.is_verified, --- m.is_verified_modified_timestamp, --- SYSDATE() AS inserted_timestamp, --- SYSDATE() AS modified_timestamp, --- id placeholder --- FROM --- seed placeholder --- s --- INNER JOIN {{ ref('price__ez_asset_metadata') }} --- m --- ON s.contract_address = m.token_address --- AND s.blockchain = m.blockchain --- WHERE --- m.is_verified --verified stablecoins only --- {% if is_incremental() %} --- AND s.contract_address NOT IN ( --- SELECT --- contract_address --- FROM --- {{ this }} --- ) --- {% endif %} --- ), + all_stablecoins AS ( SELECT * FROM crosschain_stablecoins -- UNION ALL diff --git a/models/silver/stablecoins/silver__stablecoins_daily_supply_by_mint.sql b/models/silver/stablecoins/silver__stablecoins_daily.sql similarity index 75% rename from models/silver/stablecoins/silver__stablecoins_daily_supply_by_mint.sql rename to models/silver/stablecoins/silver__stablecoins_daily.sql index b773d96c..3d6aba98 100644 --- a/models/silver/stablecoins/silver__stablecoins_daily_supply_by_mint.sql +++ b/models/silver/stablecoins/silver__stablecoins_daily.sql @@ -3,9 +3,9 @@ {{ config( materialized = 'incremental', unique_key = ['stablecoins_daily_supply_by_mint_id'], - incremental_predicates = ["dynamic_range_predicate", "block_date"], + incremental_predicates = ["dynamic_range_predicate", "balance_date"], merge_exclude_columns = ["inserted_timestamp"], - cluster_by = ['block_date','modified_timestamp::DATE'], + cluster_by = ['balance_date','modified_timestamp::DATE'], tags = ['scheduled_non_core'] ) }} @@ -26,10 +26,12 @@ WITH verified_stablecoins AS ( ) SELECT - balance_date as block_date, + balance_date, + account, mint, - sum(amount) as supply, - {{ dbt_utils.generate_surrogate_key(['block_date','mint']) }} AS stablecoins_daily_supply_by_mint_id, + amount, + owner, + {{ dbt_utils.generate_surrogate_key(['balance_date','account','mint']) }} AS stablecoins_daily_supply_by_address_id, SYSDATE() AS inserted_timestamp, SYSDATE() AS modified_timestamp, '{{ invocation_id }}' AS _invocation_id @@ -44,6 +46,6 @@ WITH verified_stablecoins AS ( -- {{ this }} -- ) -- {% endif %} - group by 1,2 + diff --git a/models/silver/stablecoins/silver__stablecoins_daily_supply_by_address.sql b/models/silver/stablecoins/silver__stablecoins_daily_supply_by_address.sql new file mode 100644 index 00000000..c1028701 --- /dev/null +++ b/models/silver/stablecoins/silver__stablecoins_daily_supply_by_address.sql @@ -0,0 +1,86 @@ +-- depends_on: {{ ref('silver__decoded_instructions_combined') }} + +{{ config( + materialized = 'incremental', + unique_key = ['stablecoins_daily_supply_by_mint_id'], + incremental_predicates = ["dynamic_range_predicate", "balance_date"], + merge_exclude_columns = ["inserted_timestamp"], + cluster_by = ['balance_date','modified_timestamp::DATE'], + tags = ['scheduled_non_core'] +) }} + +-- TODO: add lending pool addresses. Can just use deposits, but currently those tables dont have a way to relate to balances +-- need to pull out the token address for the lending deposits. + + +WITH verified_stablecoins AS ( + + SELECT + token_address, + decimals, + symbol, + NAME + FROM + {{ ref('defi__dim_stablecoins') }} + WHERE + -- is_verified + -- AND + token_address IS NOT NULL +), +lp_token_addresses as ( +select distinct(token_a_account) as token_address from solana.silver.liquidity_pools a +inner join verified_stablecoins b +on a.token_a_mint = b.token_address +where pool_address = '2EXiumdi14E9b8Fy62QcA5Uh6WdHS2b38wtSxp72Mibj' +union all +select distinct(token_b_account) as token_address from solana.silver.liquidity_pools a +inner join verified_stablecoins b +on a.token_b_mint = b.token_address +where pool_address = '2EXiumdi14E9b8Fy62QcA5Uh6WdHS2b38wtSxp72Mibj' +) +-- select * from lp_pool_token_addreses +, +bridge_vaults as ( + SELECT vault_token_address as token_address + FROM solana_dev.silver.stablecoin_bridge_vault_seed + ) +, +balance_base as ( + SELECT + balance_date, + account, + mint, + amount, + owner + FROM {{ ref('core__fact_token_daily_balances') }} a + INNER JOIN verified_stablecoins b on a.mint = b.token_address + where balance_date = '2025-10-29' + -- {% if is_incremental() %} + -- where balance_date >= ( + -- SELECT + -- MAX(balance_date) + -- FROM + -- {{ this }} + -- ) + -- {% endif %} + +) +select + balance_date, + account, + mint, + amount, + owner, + CASE WHEN b.token_address IS NOT NULL THEN amount ELSE 0 END AS dex_balance, + CASE WHEN c.token_address IS NOT NULL THEN amount ELSE 0 END AS bridge_balance, + {{ dbt_utils.generate_surrogate_key(['balance_date','account','mint']) }} AS stablecoins_daily_supply_by_address_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id + from balance_base a + left join lp_token_addresses b + on a.account = b.token_address + left join bridge_vaults c + on a.account = c.token_address + +