windowdog 4 hafta önce
ebeveyn
işleme
e506a1c4fd

+ 130 - 0
src/library/sql.sql

@@ -0,0 +1,130 @@
+with 
+    liquidity as (
+        WITH
+            pools as (
+                SELECT 
+                    distinct 
+                    project_program_id as pool_id
+                    , project
+                    , case when tr.token_bought_mint_address > tr.token_sold_mint_address 
+                        then tr.token_bought_mint_address || '-' || tr.token_sold_mint_address
+                        else tr.token_sold_mint_address || '-' || tr.token_bought_mint_address
+                        end as token_pair_mint
+                    , case when token_bought_mint_address > token_sold_mint_address then token_bought_mint_address else token_sold_mint_address end as tokenA
+                    , case when token_bought_mint_address > token_sold_mint_address then token_sold_mint_address else token_bought_mint_address end as tokenB
+                    , case when token_bought_mint_address > token_sold_mint_address then token_bought_vault else token_sold_vault end as tokenVaultA
+                    , case when token_bought_mint_address > token_sold_mint_address then token_sold_vault else token_bought_vault end as tokenVaultB
+                FROM dex_solana.trades tr
+            )
+            
+            , pool_liq as (
+                SELECT 
+                    ip.pool_id
+                    , ip.token_pair_mint
+                    , ip.tokenA 
+                    , ip.tokenB
+                    --add custom logic to only include the SOL balance of pumpdotfun
+                    , COALESCE(case when project = 'pumpdotfun' and ip.tokenA = 'So11111111111111111111111111111111111111112' 
+                        then bal_a.sol_balance
+                        else bal_a.token_balance
+                        end,0) as tokenA_balance
+                    , COALESCE(case when project = 'pumpdotfun' and ip.tokenB = 'So11111111111111111111111111111111111111112'
+                        then bal_b.sol_balance
+                        else bal_b.token_balance
+                        end,0) as tokenB_balance                
+                FROM pools ip
+                LEFT JOIN solana_utils.latest_balances bal_a ON bal_a.address = ip.tokenVaultA
+                LEFT JOIN solana_utils.latest_balances bal_b ON bal_b.address = ip.tokenVaultB
+            )
+            
+        SELECT 
+        token_pair_mint
+        , tokenA
+        , tokenB
+        , sum(
+            COALESCE(tokenA_balance*COALESCE(p_a.price, dp_a.median_price), 0) 
+            + COALESCE(tokenB_balance*COALESCE(p_b.price, dp_b.median_price),0)
+            )
+            as tvl
+        FROM pool_liq liq
+        LEFT JOIN prices.usd_latest p_a ON p_a.blockchain = 'solana' and toBase58(p_a.contract_address) = liq.tokenA
+        LEFT JOIN prices.usd_latest p_b ON p_b.blockchain = 'solana' and toBase58(p_b.contract_address) = liq.tokenB
+        LEFT JOIN dune.dune.result_dex_prices_latest_solana dp_a ON dp_a.token_mint_address = liq.tokenA
+        LEFT JOIN dune.dune.result_dex_prices_latest_solana dp_b ON dp_b.token_mint_address = liq.tokenB
+        --spam filter
+        WHERE dp_a.rolling_two_months_trades > 5000
+            and dp_a.total_holders_ever > 10000
+            and dp_b.rolling_two_months_trades > 5000
+            and dp_b.total_holders_ever > 10000
+            -- and (tokenA = '3ytUM5uGuChDdrMtgcBbENiRQgSoh4YXX9vAS2L6jX5e' OR tokenB = '3ytUM5uGuChDdrMtgcBbENiRQgSoh4YXX9vAS2L6jX5e')
+            -- and token_pair_mint like '%3ytUM5uGuChDdrMtgcBbENiRQgSoh4YXX9vAS2L6jX5e%'
+        group by 1,2,3
+    )
+
+    , pair_summaries as (
+        SELECT  
+            case when dx.token_bought_mint_address > dx.token_sold_mint_address 
+                then get_href(get_chain_explorer('solana') || '/account/' || dx.token_bought_mint_address, upper(substring(COALESCE(dx.token_bought_symbol, dx.token_bought_mint_address),1,5)))
+                || '-' 
+                || get_href(get_chain_explorer('solana') || '/account/' || dx.token_sold_mint_address, upper(substring(COALESCE(dx.token_sold_symbol, dx.token_sold_mint_address),1,5)))
+                else get_href(get_chain_explorer('solana') || '/account/' || dx.token_sold_mint_address, upper(substring(COALESCE(dx.token_sold_symbol, dx.token_sold_mint_address),1,5)))
+                || '-' 
+                || get_href(get_chain_explorer('solana') || '/account/' || dx.token_bought_mint_address, upper(substring(COALESCE(dx.token_bought_symbol, dx.token_bought_mint_address),1,5)))
+                end as token_pair
+            , case when dx.token_bought_mint_address > dx.token_sold_mint_address 
+                then dx.token_bought_mint_address || '-' || dx.token_sold_mint_address
+                else dx.token_sold_mint_address || '-' || dx.token_bought_mint_address
+                end as token_pair_mint
+            , case when dx.token_bought_mint_address > dx.token_sold_mint_address 
+                then dx.token_bought_mint_address else token_sold_mint_address 
+                end as token_a_mint
+            , case when dx.token_bought_mint_address > dx.token_sold_mint_address 
+                then dx.token_sold_mint_address else token_bought_mint_address 
+                end as token_b_mint
+            , COALESCE(sum(case when block_time > now() - interval '1' day then amount_filled else 0 end),0) as one_day_volume
+            , COALESCE(sum(case when block_time > now() - interval '7' day then amount_filled else 0 end),0) as seven_day_volume
+            , COALESCE(sum(case when block_time > now() - interval '30' day then amount_filled else 0 end),0) as thirty_day_volume
+            , COALESCE(sum(case when block_time > now() - interval '90' day then amount_filled else 0 end),0) as ninety_day_volume
+            -- , COALESCE(sum(amount_filled),0) as all_time_volume
+            , array_agg(distinct case when project = 'whirlpool' then 'orca' else project end) as projects
+            , array_agg(distinct project_program_id) as pool_ids
+        FROM (
+            SELECT 
+            *
+            , amount_usd as amount_filled
+            -- , COALESCE(amount_usd, COALESCE(token_bought_amount*dp_a.median_price, token_sold_amount*dp_b.median_price)) as amount_filled
+            FROM dex_solana.trades dx
+            WHERE block_time >= now() - interval '91' day
+            -- LEFT JOIN dune.dune.result_dex_prices_latest_solana dp_a ON dp_a.token_mint_address = dx.token_bought_mint_address AND dp_a.day = date_trunc('day', dx.block_time)
+            -- LEFT JOIN dune.dune.result_dex_prices_latest_solana dp_b ON dp_b.token_mint_address = dx.token_sold_mint_address AND dp_b.day = date_trunc('day', dx.block_time)
+            -- WHERE project_program_id NOT IN ('H83aoZ1SeCFC8J6ZYv76r7Qj9FHtnLFZNq5WAHvWr5Zn'
+            --                                 ,'2fyku8DrpwQueCc5eyTsdF6frPyroGPWdHzjEGN94ipY'
+            --                                 ,'FaLw91mzBQGq2DEi76PzGkZSaZQ1Dn1MPg9VxmH7XR99')
+            -- WHERE (token_bought_mint_address = '3S8qX1MsMqRbiwKg2cQyx7nis1oHMgaCuc9c4VfvVdPN'
+            -- OR token_sold_mint_address = '3S8qX1MsMqRbiwKg2cQyx7nis1oHMgaCuc9c4VfvVdPN')
+            -- and project = 'pumpdotfun'
+        ) dx
+        group by 1,2,3,4
+    )
+    
+SELECT 
+    p.token_pair
+    , p.token_a_mint
+    , p.token_b_mint
+    , p.one_day_volume
+    , p.seven_day_volume
+    , p.thirty_day_volume
+    , p.ninety_day_volume
+    -- , p.all_time_volume
+    , l.tvl as usd_liquidity
+    , case when l.tvl = 0 then 0 
+        else round(cast(seven_day_volume as double)/cast(l.tvl as double),0)
+        end as seven_day_volume_liquidity_ratio
+    , '||' as split
+    , p.projects
+    , p.pool_ids
+FROM pair_summaries p
+LEFT JOIN liquidity l ON p.token_a_mint = l.tokenA
+    AND p.token_b_mint = l.tokenB
+order by one_day_volume desc
+LIMIT 10000

BIN
src/librarydata/dune_excution/拉升分析-4GULMPKBJLruChBZWksZzukAg1AjSCmCTMn9ny2Xpump.xlsx