mirror of
https://github.com/FlipsideCrypto/solana-models.git
synced 2026-02-06 11:27:00 +00:00
parent
33fd81e961
commit
dc0ab1e01c
@ -27,6 +27,154 @@ This table provides a comprehensive view of cross-chain bridge activity on Solan
|
||||
- `mint`, `symbol`, `token_is_verified`: For token and asset analytics
|
||||
- `succeeded`: For transaction success analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily bridge volume by protocol
|
||||
```sql
|
||||
-- Daily bridge volume by protocol
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
platform,
|
||||
COUNT(DISTINCT tx_id) AS bridge_txns,
|
||||
SUM(amount_usd) AS volume_usd,
|
||||
COUNT(DISTINCT source_address) AS unique_users
|
||||
FROM solana.defi.ez_bridge_activity
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd IS NOT NULL
|
||||
AND succeeded = true
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 1 DESC, 4 DESC;
|
||||
```
|
||||
|
||||
### Top bridge routes (source to destination chains)
|
||||
```sql
|
||||
-- Top bridge routes (source to destination chains)
|
||||
SELECT
|
||||
source_chain,
|
||||
destination_chain,
|
||||
platform,
|
||||
COUNT(*) AS transfer_count,
|
||||
SUM(amount_usd) AS total_volume_usd,
|
||||
AVG(amount_usd) AS avg_transfer_usd
|
||||
FROM solana.defi.ez_bridge_activity
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND destination_chain IS NOT NULL
|
||||
AND succeeded = true
|
||||
GROUP BY 1, 2, 3
|
||||
ORDER BY 5 DESC
|
||||
LIMIT 20;
|
||||
```
|
||||
|
||||
### User bridge activity analysis
|
||||
```sql
|
||||
-- User bridge activity analysis
|
||||
SELECT
|
||||
source_address,
|
||||
COUNT(DISTINCT DATE_TRUNC('day', block_timestamp)) AS active_days,
|
||||
COUNT(DISTINCT platform) AS protocols_used,
|
||||
COUNT(DISTINCT destination_chain) AS chains_bridged_to,
|
||||
SUM(amount_usd) AS total_bridged_usd,
|
||||
COUNT(*) AS total_transfers
|
||||
FROM solana.defi.ez_bridge_activity
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd > 100 -- Filter small transfers
|
||||
AND succeeded = true
|
||||
GROUP BY 1
|
||||
HAVING COUNT(*) > 5 -- Active bridgers
|
||||
ORDER BY 5 DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
### Token flow analysis
|
||||
```sql
|
||||
-- Token flow analysis
|
||||
SELECT
|
||||
symbol,
|
||||
mint AS token_address,
|
||||
source_chain,
|
||||
destination_chain,
|
||||
COUNT(*) AS bridge_count,
|
||||
SUM(amount) AS total_amount,
|
||||
SUM(amount_usd) AS total_volume_usd,
|
||||
AVG(amount_usd) AS avg_transfer_usd
|
||||
FROM solana.defi.ez_bridge_activity
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND symbol IS NOT NULL
|
||||
AND succeeded = true
|
||||
GROUP BY 1, 2, 3, 4
|
||||
HAVING COUNT(*) > 10
|
||||
ORDER BY 7 DESC;
|
||||
```
|
||||
|
||||
### Bridge protocol comparison
|
||||
```sql
|
||||
-- Bridge protocol comparison
|
||||
WITH protocol_stats AS (
|
||||
SELECT
|
||||
platform,
|
||||
COUNT(DISTINCT source_address) AS unique_users,
|
||||
COUNT(*) AS total_transfers,
|
||||
AVG(amount_usd) AS avg_transfer_size,
|
||||
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY amount_usd) AS median_transfer_size,
|
||||
SUM(amount_usd) AS total_volume
|
||||
FROM solana.defi.ez_bridge_activity
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd IS NOT NULL
|
||||
AND succeeded = true
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
platform,
|
||||
unique_users,
|
||||
total_transfers,
|
||||
avg_transfer_size,
|
||||
median_transfer_size,
|
||||
total_volume,
|
||||
total_volume * 100.0 / SUM(total_volume) OVER () AS market_share_pct
|
||||
FROM protocol_stats
|
||||
ORDER BY total_volume DESC;
|
||||
```
|
||||
|
||||
### Inbound vs Outbound flow analysis
|
||||
```sql
|
||||
-- Inbound vs Outbound flow analysis
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
direction,
|
||||
platform,
|
||||
COUNT(*) AS transfer_count,
|
||||
SUM(amount_usd) AS volume_usd,
|
||||
COUNT(DISTINCT source_address) AS unique_users
|
||||
FROM solana.defi.ez_bridge_activity
|
||||
WHERE block_timestamp >= CURRENT_DATE - 14
|
||||
AND amount_usd IS NOT NULL
|
||||
AND succeeded = true
|
||||
GROUP BY 1, 2, 3
|
||||
ORDER BY 1 DESC, 5 DESC;
|
||||
```
|
||||
|
||||
### Large bridge transfers monitoring (whale activity)
|
||||
```sql
|
||||
-- Large bridge transfers monitoring (whale activity)
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
platform,
|
||||
direction,
|
||||
source_chain,
|
||||
destination_chain,
|
||||
source_address,
|
||||
destination_address,
|
||||
symbol,
|
||||
amount,
|
||||
amount_usd
|
||||
FROM solana.defi.ez_bridge_activity
|
||||
WHERE amount_usd >= 100000
|
||||
AND block_timestamp >= CURRENT_DATE - 7
|
||||
AND succeeded = true
|
||||
ORDER BY amount_usd DESC;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs bridge_platform %}
|
||||
|
||||
@ -152,6 +152,126 @@ This table captures deposit events across Solana DeFi lending protocols includin
|
||||
- `amount`, `amount_usd`: For volume analysis and value-based metrics
|
||||
- `protocol_market`: For market-specific utilization and performance analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily deposit volume by protocol
|
||||
```sql
|
||||
-- Daily lending deposits by protocol
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
platform,
|
||||
COUNT(DISTINCT tx_id) AS deposit_txns,
|
||||
COUNT(DISTINCT depositor) AS unique_depositors,
|
||||
SUM(amount) AS tokens_deposited,
|
||||
SUM(amount_usd) AS usd_deposited,
|
||||
AVG(amount_usd) AS avg_deposit_size
|
||||
FROM solana.defi.ez_lending_deposits
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd IS NOT NULL
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 1 DESC, 6 DESC;
|
||||
```
|
||||
|
||||
### Protocol market share analysis
|
||||
```sql
|
||||
-- Protocol market share analysis
|
||||
WITH protocol_totals AS (
|
||||
SELECT
|
||||
platform,
|
||||
SUM(amount_usd) AS total_usd_deposited,
|
||||
COUNT(DISTINCT depositor) AS unique_depositors,
|
||||
COUNT(*) AS total_deposits
|
||||
FROM solana.defi.ez_lending_deposits
|
||||
WHERE block_timestamp >= CURRENT_DATE - 90
|
||||
AND amount_usd IS NOT NULL
|
||||
GROUP BY platform
|
||||
)
|
||||
SELECT
|
||||
platform,
|
||||
total_usd_deposited,
|
||||
total_usd_deposited * 100.0 / SUM(total_usd_deposited) OVER () AS market_share_pct,
|
||||
unique_depositors,
|
||||
total_deposits,
|
||||
total_usd_deposited / total_deposits AS avg_deposit_size
|
||||
FROM protocol_totals
|
||||
ORDER BY total_usd_deposited DESC;
|
||||
```
|
||||
|
||||
### Depositor behavior patterns
|
||||
```sql
|
||||
-- Depositor behavior patterns
|
||||
WITH depositor_activity AS (
|
||||
SELECT
|
||||
depositor,
|
||||
COUNT(DISTINCT platform) AS protocols_used,
|
||||
COUNT(*) AS total_deposits,
|
||||
SUM(amount_usd) AS total_usd_deposited,
|
||||
MIN(block_timestamp) AS first_deposit,
|
||||
MAX(block_timestamp) AS last_deposit,
|
||||
COUNT(DISTINCT DATE_TRUNC('month', block_timestamp)) AS active_months
|
||||
FROM solana.defi.ez_lending_deposits
|
||||
WHERE amount_usd IS NOT NULL
|
||||
GROUP BY depositor
|
||||
)
|
||||
SELECT
|
||||
CASE
|
||||
WHEN total_usd_deposited < 1000 THEN '< $1K'
|
||||
WHEN total_usd_deposited < 10000 THEN '$1K-$10K'
|
||||
WHEN total_usd_deposited < 100000 THEN '$10K-$100K'
|
||||
ELSE '$100K+'
|
||||
END AS depositor_tier,
|
||||
COUNT(*) AS depositor_count,
|
||||
AVG(total_deposits) AS avg_deposits_per_user,
|
||||
AVG(protocols_used) AS avg_protocols_used,
|
||||
SUM(total_usd_deposited) AS tier_total_usd
|
||||
FROM depositor_activity
|
||||
GROUP BY depositor_tier
|
||||
ORDER BY MIN(total_usd_deposited);
|
||||
```
|
||||
|
||||
### Large deposits monitoring (whale activity)
|
||||
```sql
|
||||
-- Large deposits monitoring (whale activity)
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
platform,
|
||||
depositor,
|
||||
token_symbol,
|
||||
amount,
|
||||
amount_usd,
|
||||
protocol_market
|
||||
FROM solana.defi.ez_lending_deposits
|
||||
WHERE amount_usd >= 100000
|
||||
AND block_timestamp >= CURRENT_DATE - 7
|
||||
ORDER BY amount_usd DESC;
|
||||
```
|
||||
|
||||
### Weekly deposit momentum
|
||||
```sql
|
||||
-- Weekly deposit momentum
|
||||
WITH weekly_deposits AS (
|
||||
SELECT
|
||||
DATE_TRUNC('week', block_timestamp) AS week,
|
||||
platform,
|
||||
SUM(amount_usd) AS weekly_usd_deposited,
|
||||
COUNT(DISTINCT depositor) AS unique_depositors
|
||||
FROM solana.defi.ez_lending_deposits
|
||||
WHERE block_timestamp >= CURRENT_DATE - 84
|
||||
AND amount_usd IS NOT NULL
|
||||
GROUP BY 1, 2
|
||||
)
|
||||
SELECT
|
||||
week,
|
||||
platform,
|
||||
weekly_usd_deposited,
|
||||
LAG(weekly_usd_deposited) OVER (PARTITION BY platform ORDER BY week) AS prev_week_usd,
|
||||
(weekly_usd_deposited / NULLIF(LAG(weekly_usd_deposited) OVER (PARTITION BY platform ORDER BY week), 0) - 1) * 100 AS week_over_week_pct,
|
||||
unique_depositors
|
||||
FROM weekly_deposits
|
||||
ORDER BY week DESC, weekly_usd_deposited DESC;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs ez_lending_borrows %}
|
||||
@ -182,6 +302,124 @@ This table captures borrow events across Solana DeFi lending protocols including
|
||||
- `amount`, `amount_usd`: For borrowing volume analysis and market size metrics
|
||||
- `protocol_market`: For market-specific borrowing rates and utilization tracking
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily borrowing volume by protocol
|
||||
```sql
|
||||
-- Daily borrowing volume by protocol
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
platform,
|
||||
COUNT(DISTINCT tx_id) AS borrow_txns,
|
||||
COUNT(DISTINCT borrower) AS unique_borrowers,
|
||||
SUM(amount_usd) AS volume_usd
|
||||
FROM solana.defi.ez_lending_borrows
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd IS NOT NULL
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 1 DESC, 5 DESC;
|
||||
```
|
||||
|
||||
### Top borrowed assets analysis
|
||||
```sql
|
||||
-- Top borrowed assets analysis
|
||||
SELECT
|
||||
token_symbol,
|
||||
token_address,
|
||||
COUNT(*) AS borrow_count,
|
||||
SUM(amount) AS total_borrowed,
|
||||
SUM(amount_usd) AS total_borrowed_usd,
|
||||
AVG(amount_usd) AS avg_borrow_size_usd
|
||||
FROM solana.defi.ez_lending_borrows
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND token_symbol IS NOT NULL
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 5 DESC
|
||||
LIMIT 20;
|
||||
```
|
||||
|
||||
### Wallet specific borrow analysis
|
||||
```sql
|
||||
-- Wallet Specific Borrow Analysis
|
||||
SELECT
|
||||
b.borrower,
|
||||
b.token_address AS borrowed_token_address,
|
||||
b.token_symbol AS borrowed_token_symbol,
|
||||
DATE_TRUNC('week', b.block_timestamp) AS weekly_block_timestamp,
|
||||
SUM(b.amount) AS total_borrow_amount,
|
||||
SUM(b.amount_usd) AS total_borrow_usd,
|
||||
SUM(r.amount) AS total_repayment_amount,
|
||||
SUM(r.amount_usd) AS total_repayment_usd,
|
||||
SUM(b.amount) - COALESCE(SUM(r.amount), 0) AS net_borrowed_amount,
|
||||
SUM(b.amount_usd) - COALESCE(SUM(r.amount_usd), 0) AS net_borrowed_usd
|
||||
FROM
|
||||
solana.defi.ez_lending_borrows b
|
||||
LEFT JOIN solana.defi.ez_lending_repayments r
|
||||
ON b.borrower = r.payer
|
||||
AND b.token_address = r.token_address
|
||||
WHERE
|
||||
b.borrower = LOWER('<user_address>')
|
||||
GROUP BY 1, 2, 3, 4
|
||||
ORDER BY 4 DESC;
|
||||
```
|
||||
|
||||
### User borrowing patterns
|
||||
```sql
|
||||
-- User borrowing patterns
|
||||
WITH user_stats AS (
|
||||
SELECT
|
||||
borrower,
|
||||
COUNT(DISTINCT DATE_TRUNC('day', block_timestamp)) AS active_days,
|
||||
COUNT(DISTINCT platform) AS platforms_used,
|
||||
COUNT(DISTINCT token_address) AS assets_borrowed,
|
||||
SUM(amount_usd) AS total_borrowed_usd,
|
||||
AVG(amount_usd) AS avg_borrow_size
|
||||
FROM solana.defi.ez_lending_borrows
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd IS NOT NULL
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
CASE
|
||||
WHEN total_borrowed_usd < 1000 THEN '< $1K'
|
||||
WHEN total_borrowed_usd < 10000 THEN '$1K - $10K'
|
||||
WHEN total_borrowed_usd < 100000 THEN '$10K - $100K'
|
||||
ELSE '> $100K'
|
||||
END AS borrower_tier,
|
||||
COUNT(*) AS user_count,
|
||||
AVG(active_days) AS avg_active_days,
|
||||
AVG(platforms_used) AS avg_platforms,
|
||||
AVG(total_borrowed_usd) AS avg_total_borrowed
|
||||
FROM user_stats
|
||||
GROUP BY 1
|
||||
ORDER BY 5 DESC;
|
||||
```
|
||||
|
||||
### Protocol market share
|
||||
```sql
|
||||
-- Protocol market share
|
||||
WITH protocol_volume AS (
|
||||
SELECT
|
||||
platform,
|
||||
SUM(amount_usd) AS total_volume,
|
||||
COUNT(DISTINCT borrower) AS unique_users,
|
||||
COUNT(*) AS transaction_count
|
||||
FROM solana.defi.ez_lending_borrows
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd IS NOT NULL
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
platform,
|
||||
total_volume,
|
||||
total_volume * 100.0 / SUM(total_volume) OVER () AS market_share_pct,
|
||||
unique_users,
|
||||
transaction_count,
|
||||
total_volume / transaction_count AS avg_borrow_size
|
||||
FROM protocol_volume
|
||||
ORDER BY total_volume DESC;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
{% docs ez_lending_withdraws %}
|
||||
|
||||
@ -17,4 +17,127 @@ This table provides an enhanced view of DEX swap activity with USD pricing, toke
|
||||
## Commonly-used Fields
|
||||
- `block_timestamp`, `swapper`, `swap_from_mint`, `swap_to_mint`, `swap_from_amount_usd`, `swap_to_amount_usd`, `swap_program`
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Real swap volume calculation by DEX protocol
|
||||
```sql
|
||||
-- Calculate real swap volume by DEX protocol (includes both direct and Jupiter-routed swaps)
|
||||
SELECT
|
||||
swap_program,
|
||||
COUNT(*) AS total_swaps,
|
||||
COUNT(DISTINCT swapper) AS unique_users,
|
||||
SUM(swap_from_amount_usd) AS total_volume_usd,
|
||||
AVG(swap_from_amount_usd) AS avg_swap_size_usd
|
||||
FROM solana.defi.ez_dex_swaps
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND swap_from_amount_usd IS NOT NULL
|
||||
GROUP BY 1
|
||||
ORDER BY total_volume_usd DESC;
|
||||
```
|
||||
|
||||
### Buy/sell volume analysis for a specific token
|
||||
```sql
|
||||
-- Get buy/sell volume for JTO token across all DEXes
|
||||
WITH sells AS (
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
SUM(swap_from_amount) AS sum_sells,
|
||||
COUNT(DISTINCT swapper) AS unique_sellers
|
||||
FROM solana.defi.ez_dex_swaps
|
||||
WHERE swap_from_mint = 'jtojtomepa8beP8AuQc6eXt5FriJwfFMwQx2v2f9mCL'
|
||||
AND block_timestamp::date BETWEEN '2025-01-01' AND '2025-01-07'
|
||||
GROUP BY 1
|
||||
),
|
||||
buys AS (
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
SUM(swap_to_amount) AS sum_buys,
|
||||
COUNT(DISTINCT swapper) AS unique_buyers
|
||||
FROM solana.defi.ez_dex_swaps
|
||||
WHERE swap_to_mint = 'jtojtomepa8beP8AuQc6eXt5FriJwfFMwQx2v2f9mCL'
|
||||
AND block_timestamp::date BETWEEN '2025-01-01' AND '2025-01-07'
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
COALESCE(s.dt, b.dt) AS dt,
|
||||
COALESCE(s.sum_sells, 0) AS sell_volume,
|
||||
COALESCE(s.unique_sellers, 0) AS unique_sellers,
|
||||
COALESCE(b.sum_buys, 0) AS buy_volume,
|
||||
COALESCE(b.unique_buyers, 0) AS unique_buyers
|
||||
FROM sells s
|
||||
FULL OUTER JOIN buys b ON s.dt = b.dt
|
||||
ORDER BY dt;
|
||||
```
|
||||
|
||||
### Token pair trading analysis
|
||||
```sql
|
||||
-- Most traded token pairs by volume
|
||||
SELECT
|
||||
swap_from_symbol || ' -> ' || swap_to_symbol AS trading_pair,
|
||||
COUNT(*) AS swap_count,
|
||||
SUM(swap_from_amount_usd) AS total_volume_usd,
|
||||
AVG(swap_from_amount_usd) AS avg_swap_size,
|
||||
COUNT(DISTINCT swapper) AS unique_traders,
|
||||
COUNT(DISTINCT swap_program) AS dex_count
|
||||
FROM solana.defi.ez_dex_swaps
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND swap_from_amount_usd > 0
|
||||
AND swap_from_symbol IS NOT NULL
|
||||
AND swap_to_symbol IS NOT NULL
|
||||
GROUP BY 1
|
||||
HAVING swap_count >= 10
|
||||
ORDER BY total_volume_usd DESC
|
||||
LIMIT 50;
|
||||
```
|
||||
|
||||
### Compare Jupiter-routed vs direct DEX swaps
|
||||
```sql
|
||||
-- Compare volume of Jupiter-routed swaps vs direct DEX swaps for wSOL
|
||||
with jupiter_routed_swaps as (
|
||||
select
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
swap_from_amount
|
||||
from solana.defi.fact_swaps_jupiter_inner
|
||||
where swap_from_mint = 'So11111111111111111111111111111111111111112'
|
||||
and block_timestamp::date between '2025-05-01' and '2025-05-07')
|
||||
,
|
||||
|
||||
direct_swaps as (
|
||||
select
|
||||
tx_id,
|
||||
block_timestamp,
|
||||
swap_from_amount
|
||||
from solana.defi.fact_swaps
|
||||
where swap_from_mint = 'So11111111111111111111111111111111111111112'
|
||||
and block_timestamp::date between '2025-05-01' and '2025-05-07'
|
||||
and tx_id not in (select distinct(tx_id) from jupiter_routed_swaps) -- need to exclude the jupiter related swaps from fact_swaps
|
||||
)
|
||||
,
|
||||
|
||||
sum_jupiter as (
|
||||
select
|
||||
block_timestamp::date dt,
|
||||
sum(swap_from_amount) as jup_amt
|
||||
from jupiter_routed_swaps
|
||||
group by 1)
|
||||
|
||||
,
|
||||
sum_direct as (
|
||||
select
|
||||
block_timestamp::date dt,
|
||||
sum(swap_from_amount) as direct_amt
|
||||
from direct_swaps
|
||||
group by 1)
|
||||
|
||||
Select
|
||||
a.dt,
|
||||
a.jup_amt as swap_via_jupiter,
|
||||
b.direct_amt as direct_swap,
|
||||
a.jup_amt + b.direct_amt as total_amt
|
||||
from sum_jupiter a
|
||||
left join sum_direct b
|
||||
on a.dt = b.dt;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -23,4 +23,39 @@ This table contains one row per decoded Solana record, mapping detailed program
|
||||
- `decoded_instruction`, `decoded_accounts`, `decoded_args`, `decoding_error`: For detailed event and error analytics
|
||||
- `signers`, `succeeded`: For user attribution and transaction outcome analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily event activity by program
|
||||
```sql
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
program_id,
|
||||
COUNT(*) AS event_count,
|
||||
COUNT(DISTINCT tx_id) AS unique_transactions,
|
||||
COUNT(DISTINCT signers[0]::STRING) AS unique_signers,
|
||||
COUNT(DISTINCT event_type) AS unique_event_types
|
||||
FROM solana.core.ez_events_decoded
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 1 DESC, 3 DESC;
|
||||
```
|
||||
|
||||
### Most common event types with decoded data
|
||||
```sql
|
||||
SELECT
|
||||
program_id,
|
||||
event_type,
|
||||
decoded_instruction:name::STRING AS instruction_name,
|
||||
COUNT(*) AS occurrences,
|
||||
COUNT(DISTINCT signers[0]::STRING) AS unique_signers
|
||||
FROM solana.core.ez_events_decoded
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND decoded_instruction IS NOT NULL
|
||||
GROUP BY 1, 2, 3
|
||||
HAVING occurrences > 100
|
||||
ORDER BY occurrences DESC;
|
||||
```
|
||||
|
||||
|
||||
|
||||
{% enddocs %}
|
||||
@ -32,4 +32,96 @@ This table provides a unified view of NFT sales across multiple Solana marketpla
|
||||
- `nft_name`: Human-readable name of the NFT from metadata
|
||||
- `nft_collection_name`: Name of the collection the NFT belongs to
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily NFT marketplace volume and activity
|
||||
```sql
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
marketplace,
|
||||
COUNT(*) AS total_sales,
|
||||
COUNT(DISTINCT buyer_address) AS unique_buyers,
|
||||
COUNT(DISTINCT seller_address) AS unique_sellers,
|
||||
COUNT(DISTINCT mint) AS unique_nfts_traded,
|
||||
SUM(price) AS total_volume_native,
|
||||
SUM(price_usd) AS total_volume_usd,
|
||||
AVG(price_usd) AS avg_sale_price_usd,
|
||||
MAX(price_usd) AS highest_sale_usd
|
||||
FROM solana.nft.ez_nft_sales
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND price_usd > 0
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 1 DESC, total_volume_usd DESC;
|
||||
```
|
||||
|
||||
### Top NFT collections by volume
|
||||
```sql
|
||||
SELECT
|
||||
nft_collection_name,
|
||||
COUNT(*) AS total_sales,
|
||||
COUNT(DISTINCT mint) AS unique_nfts_sold,
|
||||
COUNT(DISTINCT buyer_address) AS unique_buyers,
|
||||
SUM(price_usd) AS total_volume_usd,
|
||||
AVG(price_usd) AS avg_price_usd,
|
||||
MIN(price_usd) AS floor_price_usd,
|
||||
MAX(price_usd) AS ceiling_price_usd,
|
||||
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY price_usd) AS median_price_usd
|
||||
FROM solana.nft.ez_nft_sales
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND price_usd > 0
|
||||
AND nft_collection_name IS NOT NULL
|
||||
GROUP BY 1
|
||||
HAVING total_sales >= 10
|
||||
ORDER BY total_volume_usd DESC
|
||||
LIMIT 50;
|
||||
```
|
||||
|
||||
### NFT flipping activity (bought and sold within short timeframe)
|
||||
```sql
|
||||
WITH nft_transactions AS (
|
||||
SELECT
|
||||
mint,
|
||||
buyer_address AS owner,
|
||||
seller_address AS previous_owner,
|
||||
block_timestamp AS purchase_time,
|
||||
price_usd AS purchase_price,
|
||||
tx_id
|
||||
FROM solana.nft.ez_nft_sales
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND price_usd > 0
|
||||
),
|
||||
flips AS (
|
||||
SELECT
|
||||
t1.mint,
|
||||
t1.owner AS flipper,
|
||||
t1.purchase_time AS buy_time,
|
||||
t2.purchase_time AS sell_time,
|
||||
t1.purchase_price AS buy_price,
|
||||
t2.purchase_price AS sell_price,
|
||||
t2.purchase_price - t1.purchase_price AS profit_usd,
|
||||
(t2.purchase_price - t1.purchase_price) / NULLIF(t1.purchase_price, 0) * 100 AS profit_pct,
|
||||
DATEDIFF('hour', t1.purchase_time, t2.purchase_time) AS hold_time_hours
|
||||
FROM nft_transactions t1
|
||||
INNER JOIN nft_transactions t2
|
||||
ON t1.mint = t2.mint
|
||||
AND t1.owner = t2.previous_owner
|
||||
AND t2.purchase_time > t1.purchase_time
|
||||
AND t2.purchase_time <= t1.purchase_time + INTERVAL '3 days'
|
||||
)
|
||||
SELECT
|
||||
mint,
|
||||
flipper,
|
||||
buy_time,
|
||||
sell_time,
|
||||
hold_time_hours,
|
||||
buy_price,
|
||||
sell_price,
|
||||
profit_usd,
|
||||
profit_pct
|
||||
FROM flips
|
||||
WHERE ABS(profit_usd) > 10
|
||||
ORDER BY profit_usd DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -29,4 +29,63 @@ This table contains transfer events for Solana and SPL tokens, including pre-par
|
||||
- `token_is_verified`: For filtering to verified/trusted tokens
|
||||
- `signer`: For transaction initiator analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily transfer volume and metrics
|
||||
```sql
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
COUNT(*) AS transfer_count,
|
||||
COUNT(DISTINCT tx_from) AS unique_senders,
|
||||
COUNT(DISTINCT tx_to) AS unique_receivers,
|
||||
COUNT(DISTINCT mint) AS unique_tokens,
|
||||
SUM(amount_usd) AS total_volume_usd,
|
||||
AVG(amount_usd) AS avg_transfer_usd,
|
||||
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY amount_usd) AS median_transfer_usd
|
||||
FROM solana.core.ez_transfers
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount_usd > 0
|
||||
GROUP BY 1
|
||||
ORDER BY 1 DESC;
|
||||
```
|
||||
|
||||
### Top token transfer routes
|
||||
```sql
|
||||
SELECT
|
||||
tx_from,
|
||||
tx_to,
|
||||
symbol,
|
||||
mint,
|
||||
COUNT(*) AS transfer_count,
|
||||
SUM(amount) AS total_amount,
|
||||
SUM(amount_usd) AS total_usd,
|
||||
AVG(amount_usd) AS avg_transfer_usd
|
||||
FROM solana.core.ez_transfers
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND amount_usd IS NOT NULL
|
||||
GROUP BY 1, 2, 3, 4
|
||||
HAVING total_usd > 10000
|
||||
ORDER BY total_usd DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
### Token velocity analysis
|
||||
```sql
|
||||
SELECT
|
||||
mint,
|
||||
symbol,
|
||||
COUNT(*) AS transfer_count,
|
||||
COUNT(DISTINCT tx_from) AS unique_senders,
|
||||
COUNT(DISTINCT tx_to) AS unique_receivers,
|
||||
SUM(amount_usd) AS total_volume_usd,
|
||||
COUNT(DISTINCT DATE(block_timestamp)) AS active_days,
|
||||
SUM(amount_usd) / NULLIF(COUNT(DISTINCT DATE(block_timestamp)), 0) AS daily_avg_volume_usd
|
||||
FROM solana.core.ez_transfers
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND amount_usd > 0
|
||||
GROUP BY 1, 2
|
||||
HAVING total_volume_usd > 1000
|
||||
ORDER BY total_volume_usd DESC;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
|
||||
@ -24,4 +24,47 @@ This table records every event emitted by on-chain Solana programs during transa
|
||||
- `instruction`, `inner_instruction`: For instruction-level analytics
|
||||
- `signers`, `succeeded`: For user attribution and transaction outcome analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Event distribution by program with inner instruction metrics
|
||||
```sql
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
program_id,
|
||||
COUNT(*) AS event_count,
|
||||
COUNT(DISTINCT tx_id) AS unique_transactions,
|
||||
AVG(ARRAY_SIZE(inner_instruction_events)) AS avg_inner_events,
|
||||
MAX(ARRAY_SIZE(inner_instruction_events)) AS max_inner_events
|
||||
FROM solana.core.fact_events
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 1 DESC, 3 DESC;
|
||||
```
|
||||
|
||||
### Simple event count by program
|
||||
```sql
|
||||
SELECT
|
||||
program_id,
|
||||
COUNT(*) AS total_events
|
||||
FROM solana.core.fact_events
|
||||
WHERE block_timestamp >= CURRENT_DATE - 1
|
||||
GROUP BY program_id
|
||||
ORDER BY total_events DESC
|
||||
LIMIT 20;
|
||||
```
|
||||
|
||||
### Recent events with basic details
|
||||
```sql
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
program_id,
|
||||
instruction_index,
|
||||
data
|
||||
FROM solana.core.fact_events
|
||||
WHERE block_timestamp >= CURRENT_TIMESTAMP - INTERVAL '1 hour'
|
||||
ORDER BY block_timestamp DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -24,4 +24,49 @@ This table records every event that occurs within inner instructions (Cross-Prog
|
||||
- `instruction`: For instruction-level analytics
|
||||
- `signers`, `succeeded`: For user attribution and transaction outcome analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Count of inner instructions by program
|
||||
```sql
|
||||
SELECT
|
||||
program_id,
|
||||
COUNT(*) AS inner_instruction_count,
|
||||
COUNT(DISTINCT tx_id) AS unique_transactions
|
||||
FROM solana.core.fact_events_inner
|
||||
WHERE block_timestamp >= CURRENT_DATE - 1
|
||||
GROUP BY program_id
|
||||
ORDER BY inner_instruction_count DESC
|
||||
LIMIT 20;
|
||||
```
|
||||
|
||||
### Simple inner instruction details
|
||||
```sql
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
program_id,
|
||||
instruction_index,
|
||||
inner_index,
|
||||
instruction
|
||||
FROM solana.core.fact_events_inner
|
||||
WHERE block_timestamp >= CURRENT_TIMESTAMP - INTERVAL '1 hour'
|
||||
ORDER BY block_timestamp DESC, tx_id, instruction_index, inner_index
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
### Transactions with nested instructions
|
||||
```sql
|
||||
SELECT
|
||||
tx_id,
|
||||
COUNT(*) AS total_inner_instructions,
|
||||
COUNT(DISTINCT program_id) AS programs_called,
|
||||
MAX(inner_index) + 1 AS max_nesting_depth
|
||||
FROM solana.core.fact_events_inner
|
||||
WHERE block_timestamp >= CURRENT_DATE - 1
|
||||
GROUP BY tx_id
|
||||
HAVING total_inner_instructions > 1
|
||||
ORDER BY total_inner_instructions DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -17,14 +17,90 @@ This table tracks stake accounts on the Solana blockchain, capturing stake deleg
|
||||
- Provides stake context for `gov.fact_rewards_voting`
|
||||
|
||||
## Commonly-used Fields
|
||||
- `block_timestamp`: Timestamp when the stake account event occurred
|
||||
- `tx_id`: Unique transaction identifier for the stake account event
|
||||
- `stake_account`: Address of the stake account
|
||||
- `vote_pubkey`: Vote account that the stake is delegated to
|
||||
- `authority`: Address with authority over the stake account
|
||||
- `stake_balance`: Current stake balance of the account
|
||||
- `stake_type`: Type of stake (e.g., 'active', 'inactive', 'activating', 'deactivating')
|
||||
- `lockup_epoch`: Epoch when stake lockup expires
|
||||
- `custodian`: Address with custody over the stake account
|
||||
- `epoch`: Epoch number for time-series and epoch-based analysis
|
||||
- `stake_pubkey`: Unique stake account address for account tracking
|
||||
- `vote_pubkey`: Vote account that stake is delegated to (validator identification)
|
||||
- `authorized_staker`: Address with staking authority over the account
|
||||
- `authorized_withdrawer`: Address with withdrawal authority over the account
|
||||
- `active_stake`: Current active stake amount in SOL
|
||||
- `activation_epoch`, `deactivation_epoch`: Epochs when stake becomes active/inactive
|
||||
- `type_stake`: Stake account type and status
|
||||
- `account_sol`: Total SOL balance in the stake account
|
||||
- `lockup`: Lockup configuration and restrictions
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Current epoch staking summary by delegator
|
||||
```sql
|
||||
SELECT
|
||||
authorized_staker,
|
||||
COUNT(DISTINCT stake_pubkey) AS num_stake_accounts,
|
||||
COUNT(DISTINCT vote_pubkey) AS num_validators_delegated,
|
||||
SUM(active_stake) AS total_active_stake_sol
|
||||
FROM solana.gov.fact_stake_accounts
|
||||
WHERE epoch = (SELECT MAX(epoch) FROM solana.gov.fact_stake_accounts)
|
||||
AND active_stake > 0
|
||||
GROUP BY authorized_staker
|
||||
HAVING total_active_stake_sol > 100
|
||||
ORDER BY total_active_stake_sol DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
### Stake account lifecycle analysis
|
||||
```sql
|
||||
SELECT
|
||||
epoch,
|
||||
COUNT(DISTINCT stake_pubkey) AS total_stake_accounts,
|
||||
SUM(active_stake) AS total_active_stake_sol,
|
||||
COUNT(DISTINCT CASE WHEN activation_epoch = epoch THEN stake_pubkey END) AS newly_activated,
|
||||
COUNT(DISTINCT CASE WHEN deactivation_epoch = epoch THEN stake_pubkey END) AS newly_deactivated,
|
||||
COUNT(DISTINCT vote_pubkey) AS validators_with_stake
|
||||
FROM solana.gov.fact_stake_accounts
|
||||
WHERE epoch >= (SELECT MAX(epoch) - 10 FROM solana.gov.fact_stake_accounts)
|
||||
GROUP BY epoch
|
||||
ORDER BY epoch DESC;
|
||||
```
|
||||
|
||||
### Validator stake distribution analysis
|
||||
```sql
|
||||
SELECT
|
||||
vote_pubkey,
|
||||
COUNT(DISTINCT stake_pubkey) AS delegated_accounts,
|
||||
COUNT(DISTINCT authorized_staker) AS unique_delegators,
|
||||
SUM(active_stake) AS total_delegated_sol,
|
||||
AVG(active_stake) AS avg_delegation_sol,
|
||||
MIN(activation_epoch) AS earliest_activation,
|
||||
MAX(CASE WHEN deactivation_epoch = 18446744073709551615 THEN NULL ELSE deactivation_epoch END) AS latest_deactivation
|
||||
FROM solana.gov.fact_stake_accounts
|
||||
WHERE epoch = (SELECT MAX(epoch) FROM solana.gov.fact_stake_accounts)
|
||||
AND vote_pubkey IS NOT NULL
|
||||
AND active_stake > 0
|
||||
GROUP BY vote_pubkey
|
||||
HAVING total_delegated_sol > 1000
|
||||
ORDER BY total_delegated_sol DESC
|
||||
LIMIT 50;
|
||||
```
|
||||
|
||||
### Large stake accounts monitoring
|
||||
```sql
|
||||
SELECT
|
||||
epoch,
|
||||
stake_pubkey,
|
||||
vote_pubkey,
|
||||
authorized_staker,
|
||||
authorized_withdrawer,
|
||||
active_stake AS active_stake_sol,
|
||||
account_sol AS total_balance_sol,
|
||||
activation_epoch,
|
||||
CASE
|
||||
WHEN deactivation_epoch = 18446744073709551615 THEN 'Active'
|
||||
ELSE 'Deactivating at epoch ' || deactivation_epoch
|
||||
END AS status
|
||||
FROM solana.gov.fact_stake_accounts
|
||||
WHERE epoch = (SELECT MAX(epoch) FROM solana.gov.fact_stake_accounts)
|
||||
AND active_stake >= 10000 -- 10K+ SOL stakes
|
||||
ORDER BY active_stake DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -24,4 +24,138 @@ This table contains deposit and withdrawal actions with stake pools on the Solan
|
||||
- `address`: For user and pool address analysis
|
||||
- `succeeded`: For transaction success analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily liquid staking activity by protocol
|
||||
```sql
|
||||
-- Daily liquid staking activity by protocol
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
stake_pool_name AS platform,
|
||||
action,
|
||||
COUNT(DISTINCT tx_id) AS action_txns,
|
||||
COUNT(DISTINCT address) AS unique_users,
|
||||
SUM(amount) AS total_amount,
|
||||
AVG(amount) AS avg_amount_per_action
|
||||
FROM solana.defi.fact_stake_pool_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND succeeded = true
|
||||
AND amount IS NOT NULL
|
||||
GROUP BY 1, 2, 3
|
||||
ORDER BY 1 DESC, 6 DESC;
|
||||
```
|
||||
|
||||
### Stake pool market share analysis
|
||||
```sql
|
||||
-- Stake pool market share analysis
|
||||
WITH pool_totals AS (
|
||||
SELECT
|
||||
stake_pool_name,
|
||||
SUM(CASE WHEN action = 'deposit' THEN amount ELSE 0 END) AS total_deposits,
|
||||
SUM(CASE WHEN action = 'withdraw' THEN amount ELSE 0 END) AS total_withdrawals,
|
||||
COUNT(DISTINCT address) AS unique_users,
|
||||
COUNT(*) AS total_actions
|
||||
FROM solana.defi.fact_stake_pool_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 90
|
||||
AND succeeded = true
|
||||
AND amount IS NOT NULL
|
||||
GROUP BY stake_pool_name
|
||||
)
|
||||
SELECT
|
||||
stake_pool_name,
|
||||
total_deposits,
|
||||
total_deposits * 100.0 / SUM(total_deposits) OVER () AS deposit_market_share_pct,
|
||||
total_withdrawals,
|
||||
total_deposits - total_withdrawals AS net_deposits,
|
||||
unique_users,
|
||||
total_actions,
|
||||
total_deposits / NULLIF(total_actions, 0) AS avg_action_size
|
||||
FROM pool_totals
|
||||
ORDER BY total_deposits DESC;
|
||||
```
|
||||
|
||||
### User staking behavior patterns
|
||||
```sql
|
||||
-- User staking behavior patterns
|
||||
WITH user_activity AS (
|
||||
SELECT
|
||||
address AS user_address,
|
||||
COUNT(DISTINCT stake_pool_name) AS pools_used,
|
||||
COUNT(DISTINCT action) AS action_types_used,
|
||||
COUNT(*) AS total_actions,
|
||||
SUM(CASE WHEN action = 'deposit' THEN amount ELSE 0 END) AS total_deposits,
|
||||
SUM(CASE WHEN action = 'withdraw' THEN amount ELSE 0 END) AS total_withdrawals,
|
||||
MIN(block_timestamp) AS first_action,
|
||||
MAX(block_timestamp) AS last_action
|
||||
FROM solana.defi.fact_stake_pool_actions
|
||||
WHERE succeeded = true
|
||||
AND amount IS NOT NULL
|
||||
GROUP BY address
|
||||
)
|
||||
SELECT
|
||||
CASE
|
||||
WHEN total_deposits < 1 THEN '< 1 SOL'
|
||||
WHEN total_deposits < 10 THEN '1-10 SOL'
|
||||
WHEN total_deposits < 100 THEN '10-100 SOL'
|
||||
WHEN total_deposits < 1000 THEN '100-1K SOL'
|
||||
ELSE '1K+ SOL'
|
||||
END AS user_tier,
|
||||
COUNT(*) AS user_count,
|
||||
AVG(total_actions) AS avg_actions_per_user,
|
||||
AVG(pools_used) AS avg_pools_used,
|
||||
SUM(total_deposits) AS tier_total_deposits,
|
||||
SUM(total_withdrawals) AS tier_total_withdrawals
|
||||
FROM user_activity
|
||||
GROUP BY user_tier
|
||||
ORDER BY MIN(total_deposits);
|
||||
```
|
||||
|
||||
### Stake pool performance comparison
|
||||
```sql
|
||||
-- Stake pool performance comparison
|
||||
WITH pool_metrics AS (
|
||||
SELECT
|
||||
stake_pool_name,
|
||||
COUNT(DISTINCT address) AS unique_users,
|
||||
COUNT(*) AS total_actions,
|
||||
SUM(CASE WHEN action = 'deposit' THEN amount ELSE 0 END) AS total_deposits,
|
||||
SUM(CASE WHEN action = 'withdraw' THEN amount ELSE 0 END) AS total_withdrawals,
|
||||
AVG(CASE WHEN action = 'deposit' THEN amount END) AS avg_deposit_size,
|
||||
COUNT(CASE WHEN succeeded = false THEN 1 END) * 100.0 / COUNT(*) AS failure_rate_pct
|
||||
FROM solana.defi.fact_stake_pool_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND amount IS NOT NULL
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
stake_pool_name,
|
||||
unique_users,
|
||||
total_actions,
|
||||
total_deposits,
|
||||
total_withdrawals,
|
||||
total_deposits - total_withdrawals AS net_flow,
|
||||
avg_deposit_size,
|
||||
failure_rate_pct,
|
||||
total_actions / NULLIF(unique_users, 0) AS actions_per_user
|
||||
FROM pool_metrics
|
||||
ORDER BY total_deposits DESC;
|
||||
```
|
||||
|
||||
### Large staking actions monitoring
|
||||
```sql
|
||||
-- Large staking actions monitoring (whale activity)
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
stake_pool_name AS platform,
|
||||
action,
|
||||
address AS user_address,
|
||||
amount,
|
||||
succeeded
|
||||
FROM solana.defi.fact_stake_pool_actions
|
||||
WHERE amount >= 1000 -- Large stakes (1000+ SOL)
|
||||
AND block_timestamp >= CURRENT_DATE - 7
|
||||
ORDER BY amount DESC;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -14,6 +14,54 @@ This table contains each intermediate swap that is part of a Jupiter route, repr
|
||||
- Example queries: buy/sell volume for a token routed on Jupiter, compare volume of Jupiter-routed swaps vs. direct DEX swaps
|
||||
|
||||
## Commonly-used Fields
|
||||
- `block_timestamp`, `swap_index`, `swap_from_mint`, `swap_to_mint`, `swap_from_amount`, `swap_to_amount`, `program_id`
|
||||
- `block_timestamp`, `swap_index`, `swap_from_mint`, `swap_to_mint`, `swap_from_amount`, `swap_to_amount`, `swap_program_id`, `aggregator_program_id`
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Analyze Jupiter routing for a specific token
|
||||
```sql
|
||||
-- Get number of swaps that routed through Jupiter for PYTH token
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
SUM(swap_from_amount) AS daily_pyth_swapped_from,
|
||||
COUNT(*) AS num_intermediate_swaps,
|
||||
COUNT(DISTINCT tx_id) AS num_jupiter_transactions,
|
||||
COUNT(DISTINCT swap_program_id) AS unique_dexes_used
|
||||
FROM solana.defi.fact_swaps_jupiter_inner
|
||||
WHERE swap_from_mint = 'HZ1JovNiVvGrGNiiYvEozEVgZ58xaU3RKwX8eACQBCt3'
|
||||
AND block_timestamp::date BETWEEN '2025-01-01' AND '2025-01-07'
|
||||
GROUP BY 1
|
||||
ORDER BY dt;
|
||||
```
|
||||
|
||||
### Jupiter DEX usage and routing analysis
|
||||
```sql
|
||||
-- Analyze which DEXes Jupiter routes through most frequently
|
||||
SELECT
|
||||
l.address_name AS dex_program,
|
||||
COUNT(*) AS total_route_steps,
|
||||
COUNT(DISTINCT tx_id) AS unique_transactions,
|
||||
SUM(swap_from_amount) AS total_volume_routed,
|
||||
AVG(swap_from_amount) AS avg_swap_size
|
||||
FROM solana.defi.fact_swaps_jupiter_inner j
|
||||
LEFT JOIN solana.core.dim_labels l ON j.swap_program_id = l.address
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
GROUP BY 1
|
||||
ORDER BY total_route_steps DESC;
|
||||
```
|
||||
|
||||
### Jupiter routing complexity analysis
|
||||
```sql
|
||||
-- Analyze the complexity of Jupiter routes (number of steps per transaction)
|
||||
SELECT
|
||||
COUNT(DISTINCT swap_index) AS route_steps,
|
||||
COUNT(*) AS num_transactions,
|
||||
AVG(swap_from_amount) AS avg_initial_amount,
|
||||
COUNT(*) * 100.0 / SUM(COUNT(*)) OVER () AS pct_of_transactions
|
||||
FROM solana.defi.fact_swaps_jupiter_inner
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
GROUP BY tx_id, 1
|
||||
ORDER BY route_steps;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -16,4 +16,110 @@ This table contains summary information for Jupiter aggregator swaps, representi
|
||||
## Commonly-used Fields
|
||||
- `block_timestamp`, `swapper`, `swap_from_mint`, `swap_to_mint`, `swap_from_amount`, `swap_to_amount`, `is_dca_swap`, `is_limit_swap`
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### User-initiated buy/sell analysis for Jupiter swaps
|
||||
```sql
|
||||
-- Number of buy and sell swaps for JTO token on Jupiter
|
||||
WITH sells AS (
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
SUM(swap_from_amount) AS sum_sells,
|
||||
COUNT(DISTINCT swapper) AS unique_sellers
|
||||
FROM solana.defi.fact_swaps_jupiter_summary
|
||||
WHERE swap_from_mint = 'jtojtomepa8beP8AuQc6eXt5FriJwfFMwQx2v2f9mCL'
|
||||
AND block_timestamp::date BETWEEN '2025-01-01' AND '2025-01-07'
|
||||
GROUP BY 1
|
||||
),
|
||||
buys AS (
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
SUM(swap_to_amount) AS sum_buys,
|
||||
COUNT(DISTINCT swapper) AS unique_buyers
|
||||
FROM solana.defi.fact_swaps_jupiter_summary
|
||||
WHERE swap_to_mint = 'jtojtomepa8beP8AuQc6eXt5FriJwfFMwQx2v2f9mCL'
|
||||
AND block_timestamp::date BETWEEN '2025-01-01' AND '2025-01-07'
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
COALESCE(s.dt, b.dt) AS dt,
|
||||
COALESCE(s.sum_sells, 0) AS sell_volume,
|
||||
COALESCE(s.unique_sellers, 0) AS unique_sellers,
|
||||
COALESCE(b.sum_buys, 0) AS buy_volume,
|
||||
COALESCE(b.unique_buyers, 0) AS unique_buyers
|
||||
FROM sells s
|
||||
FULL OUTER JOIN buys b ON s.dt = b.dt
|
||||
ORDER BY dt;
|
||||
```
|
||||
|
||||
### Jupiter DCA and limit order analysis
|
||||
```sql
|
||||
-- Analyze special Jupiter features usage
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
COUNT(*) AS total_jupiter_swaps,
|
||||
COUNT(CASE WHEN is_dca_swap THEN 1 END) AS dca_swaps,
|
||||
COUNT(CASE WHEN is_limit_swap THEN 1 END) AS limit_swaps,
|
||||
COUNT(CASE WHEN NOT is_dca_swap AND NOT is_limit_swap THEN 1 END) AS regular_swaps,
|
||||
COUNT(CASE WHEN is_dca_swap THEN 1 END) * 100.0 / COUNT(*) AS dca_percentage,
|
||||
COUNT(CASE WHEN is_limit_swap THEN 1 END) * 100.0 / COUNT(*) AS limit_percentage
|
||||
FROM solana.defi.fact_swaps_jupiter_summary
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
GROUP BY 1
|
||||
ORDER BY dt;
|
||||
```
|
||||
|
||||
### Jupiter user behavior and intent analysis
|
||||
```sql
|
||||
-- Analyze intended swap activity and user patterns on Jupiter
|
||||
SELECT
|
||||
COUNT(DISTINCT swapper) AS unique_users,
|
||||
COUNT(*) AS total_swaps,
|
||||
AVG(swap_from_amount) AS avg_input_amount,
|
||||
AVG(swap_to_amount) AS avg_output_amount,
|
||||
COUNT(*) / COUNT(DISTINCT swapper) AS avg_swaps_per_user,
|
||||
COUNT(DISTINCT swap_from_mint) AS unique_input_tokens,
|
||||
COUNT(DISTINCT swap_to_mint) AS unique_output_tokens
|
||||
FROM solana.defi.fact_swaps_jupiter_summary
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND succeeded = true;
|
||||
```
|
||||
|
||||
### Compare Jupiter vs all DEX activity
|
||||
```sql
|
||||
-- Compare Jupiter summary volume vs total DEX volume
|
||||
WITH jupiter_volume AS (
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
SUM(swap_from_amount) AS jupiter_volume,
|
||||
COUNT(*) AS jupiter_swaps,
|
||||
COUNT(DISTINCT swapper) AS jupiter_users
|
||||
FROM solana.defi.fact_swaps_jupiter_summary
|
||||
WHERE block_timestamp::date BETWEEN '2025-01-01' AND '2025-01-07'
|
||||
GROUP BY 1
|
||||
),
|
||||
total_dex_volume AS (
|
||||
SELECT
|
||||
block_timestamp::date AS dt,
|
||||
SUM(swap_from_amount) AS total_dex_volume,
|
||||
COUNT(*) AS total_swaps,
|
||||
COUNT(DISTINCT swapper) AS total_users
|
||||
FROM solana.defi.fact_swaps
|
||||
WHERE block_timestamp::date BETWEEN '2025-01-01' AND '2025-01-07'
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
j.dt,
|
||||
j.jupiter_volume,
|
||||
t.total_dex_volume,
|
||||
j.jupiter_volume * 100.0 / t.total_dex_volume AS jupiter_market_share_pct,
|
||||
j.jupiter_swaps,
|
||||
t.total_swaps,
|
||||
j.jupiter_users,
|
||||
t.total_users
|
||||
FROM jupiter_volume j
|
||||
JOIN total_dex_volume t ON j.dt = t.dt
|
||||
ORDER BY j.dt;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -24,4 +24,108 @@ This table contains information on all token burn events on the Solana blockchai
|
||||
- `mint_standard_type`: For token standard analysis
|
||||
- `succeeded`: For transaction success analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily token burn activity
|
||||
```sql
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
COUNT(*) AS burn_count,
|
||||
COUNT(DISTINCT burn_authority) AS unique_burners,
|
||||
COUNT(DISTINCT mint) AS unique_tokens_burned,
|
||||
SUM(burn_amount / POW(10, COALESCE(decimal, 0))) AS total_tokens_burned
|
||||
FROM solana.defi.fact_token_burn_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND succeeded = TRUE
|
||||
GROUP BY 1
|
||||
ORDER BY 1 DESC;
|
||||
```
|
||||
|
||||
### Top tokens by burn volume
|
||||
```sql
|
||||
SELECT
|
||||
mint,
|
||||
COUNT(*) AS burn_events,
|
||||
SUM(burn_amount / POW(10, COALESCE(decimal, 0))) AS total_burned_tokens,
|
||||
COUNT(DISTINCT burn_authority) AS unique_burners,
|
||||
COUNT(DISTINCT DATE(block_timestamp)) AS active_days,
|
||||
MAX(burn_amount / POW(10, COALESCE(decimal, 0))) AS largest_burn_tokens,
|
||||
AVG(burn_amount / POW(10, COALESCE(decimal, 0))) AS avg_burn_size_tokens
|
||||
FROM solana.defi.fact_token_burn_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND succeeded = TRUE
|
||||
GROUP BY mint
|
||||
HAVING burn_events > 5
|
||||
ORDER BY total_burned_tokens DESC
|
||||
LIMIT 50;
|
||||
```
|
||||
|
||||
### Burn patterns by hour of day
|
||||
```sql
|
||||
SELECT
|
||||
EXTRACT(HOUR FROM block_timestamp) AS hour_of_day,
|
||||
COUNT(*) AS burn_count,
|
||||
SUM(burn_amount / POW(10, COALESCE(decimal, 0))) AS total_burned_tokens,
|
||||
AVG(burn_amount / POW(10, COALESCE(decimal, 0))) AS avg_burn_tokens,
|
||||
COUNT(DISTINCT burn_authority) AS unique_burners
|
||||
FROM solana.defi.fact_token_burn_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND succeeded = TRUE
|
||||
GROUP BY 1
|
||||
ORDER BY 1;
|
||||
```
|
||||
|
||||
### Large token burns (whale activity)
|
||||
```sql
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
burn_authority,
|
||||
mint,
|
||||
burn_amount,
|
||||
burn_amount / POW(10, COALESCE(decimal, 0)) AS burn_amount_normalized,
|
||||
event_type,
|
||||
succeeded
|
||||
FROM solana.defi.fact_token_burn_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 1
|
||||
AND burn_amount > 1000000 -- Large raw amounts
|
||||
AND succeeded = TRUE
|
||||
ORDER BY burn_amount DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
### Token burn velocity (rate of burns over time)
|
||||
```sql
|
||||
WITH daily_burns AS (
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
mint,
|
||||
SUM(burn_amount / POW(10, COALESCE(decimal, 0))) AS daily_burned_tokens,
|
||||
COUNT(*) AS burn_events
|
||||
FROM solana.defi.fact_token_burn_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND succeeded = TRUE
|
||||
GROUP BY 1, 2
|
||||
),
|
||||
burn_velocity AS (
|
||||
SELECT
|
||||
mint,
|
||||
AVG(daily_burned_tokens) AS avg_daily_burn_tokens,
|
||||
STDDEV(daily_burned_tokens) AS stddev_daily_burn_tokens,
|
||||
MAX(daily_burned_tokens) AS max_daily_burn_tokens,
|
||||
COUNT(DISTINCT date) AS active_days
|
||||
FROM daily_burns
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
mint,
|
||||
avg_daily_burn_tokens,
|
||||
stddev_daily_burn_tokens,
|
||||
max_daily_burn_tokens,
|
||||
active_days,
|
||||
stddev_daily_burn_tokens / NULLIF(avg_daily_burn_tokens, 0) AS burn_volatility
|
||||
FROM burn_velocity
|
||||
WHERE avg_daily_burn_tokens > 100
|
||||
ORDER BY avg_daily_burn_tokens DESC;
|
||||
```
|
||||
{% enddocs %}
|
||||
@ -24,4 +24,151 @@ This table contains information on all token mint events on the Solana blockchai
|
||||
- `mint_standard_type`: For token standard analysis
|
||||
- `succeeded`: For transaction success analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily token minting activity
|
||||
```sql
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
COUNT(*) AS mint_count,
|
||||
COUNT(DISTINCT mint_authority) AS unique_minters,
|
||||
COUNT(DISTINCT mint) AS unique_tokens_minted,
|
||||
SUM(mint_amount / POW(10, COALESCE(decimal, 0))) AS total_tokens_minted
|
||||
FROM solana.defi.fact_token_mint_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND succeeded = TRUE
|
||||
GROUP BY 1
|
||||
ORDER BY 1 DESC;
|
||||
```
|
||||
|
||||
### Top minting authorities by volume
|
||||
```sql
|
||||
SELECT
|
||||
mint_authority,
|
||||
COUNT(DISTINCT mint) AS unique_tokens,
|
||||
COUNT(*) AS mint_events,
|
||||
SUM(mint_amount / POW(10, COALESCE(decimal, 0))) AS total_minted_tokens,
|
||||
AVG(mint_amount / POW(10, COALESCE(decimal, 0))) AS avg_mint_size_tokens,
|
||||
MAX(mint_amount / POW(10, COALESCE(decimal, 0))) AS largest_mint_tokens,
|
||||
COUNT(DISTINCT DATE(block_timestamp)) AS active_days
|
||||
FROM solana.defi.fact_token_mint_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND succeeded = TRUE
|
||||
GROUP BY mint_authority
|
||||
HAVING mint_events > 10
|
||||
ORDER BY total_minted_tokens DESC
|
||||
LIMIT 50;
|
||||
```
|
||||
|
||||
### Token supply expansion analysis
|
||||
```sql
|
||||
WITH mint_burn_comparison AS (
|
||||
SELECT
|
||||
m.mint,
|
||||
COALESCE(SUM(m.mint_amount / POW(10, COALESCE(m.decimal, 0))), 0) AS total_minted,
|
||||
COALESCE(b.total_burned, 0) AS total_burned
|
||||
FROM solana.defi.fact_token_mint_actions m
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
mint,
|
||||
SUM(burn_amount / POW(10, COALESCE(decimal, 0))) AS total_burned
|
||||
FROM solana.defi.fact_token_burn_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND succeeded = TRUE
|
||||
GROUP BY 1
|
||||
) b ON m.mint = b.mint
|
||||
WHERE m.block_timestamp >= CURRENT_DATE - 7
|
||||
AND m.succeeded = TRUE
|
||||
GROUP BY 1, b.total_burned
|
||||
)
|
||||
SELECT
|
||||
mint,
|
||||
total_minted,
|
||||
total_burned,
|
||||
total_minted - total_burned AS net_supply_change,
|
||||
CASE
|
||||
WHEN total_burned = 0 THEN 'Pure Inflation'
|
||||
WHEN total_minted > total_burned THEN 'Net Inflation'
|
||||
WHEN total_minted < total_burned THEN 'Net Deflation'
|
||||
ELSE 'Balanced'
|
||||
END AS supply_dynamics
|
||||
FROM mint_burn_comparison
|
||||
WHERE total_minted > 0 OR total_burned > 0
|
||||
ORDER BY ABS(total_minted - total_burned) DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
### Minting velocity and patterns
|
||||
```sql
|
||||
WITH hourly_mints AS (
|
||||
SELECT
|
||||
DATE_TRUNC('hour', block_timestamp) AS hour,
|
||||
mint,
|
||||
COUNT(*) AS mint_events,
|
||||
SUM(mint_amount / POW(10, COALESCE(decimal, 0))) AS hourly_minted_tokens
|
||||
FROM solana.defi.fact_token_mint_actions
|
||||
WHERE block_timestamp >= CURRENT_TIMESTAMP - INTERVAL '24 hours'
|
||||
AND succeeded = TRUE
|
||||
GROUP BY 1, 2
|
||||
)
|
||||
SELECT
|
||||
hour,
|
||||
COUNT(DISTINCT mint) AS active_tokens,
|
||||
SUM(mint_events) AS total_mint_events,
|
||||
SUM(hourly_minted_tokens) AS total_minted_tokens,
|
||||
AVG(hourly_minted_tokens) AS avg_token_mint_amount,
|
||||
MAX(hourly_minted_tokens) AS max_token_mint_amount
|
||||
FROM hourly_mints
|
||||
GROUP BY 1
|
||||
ORDER BY 1 DESC;
|
||||
```
|
||||
|
||||
### Large minting events (potential inflation events)
|
||||
```sql
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
mint_authority,
|
||||
mint,
|
||||
mint_amount,
|
||||
mint_amount / POW(10, COALESCE(decimal, 0)) AS mint_amount_normalized,
|
||||
event_type,
|
||||
succeeded
|
||||
FROM solana.defi.fact_token_mint_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 1
|
||||
AND mint_amount > 1000000 -- Large raw amounts
|
||||
AND succeeded = TRUE
|
||||
ORDER BY mint_amount DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
### Token creation and initial mints
|
||||
```sql
|
||||
WITH first_mints AS (
|
||||
SELECT
|
||||
mint,
|
||||
MIN(block_timestamp) AS first_mint_time,
|
||||
FIRST_VALUE(mint_authority) OVER (
|
||||
PARTITION BY mint
|
||||
ORDER BY block_timestamp
|
||||
) AS initial_minter,
|
||||
FIRST_VALUE(mint_amount / POW(10, COALESCE(decimal, 0))) OVER (
|
||||
PARTITION BY mint
|
||||
ORDER BY block_timestamp
|
||||
) AS initial_supply_normalized
|
||||
FROM solana.defi.fact_token_mint_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 7
|
||||
AND succeeded = TRUE
|
||||
)
|
||||
SELECT DISTINCT
|
||||
DATE_TRUNC('day', first_mint_time) AS launch_date,
|
||||
mint,
|
||||
initial_minter,
|
||||
initial_supply_normalized,
|
||||
first_mint_time
|
||||
FROM first_mints
|
||||
ORDER BY first_mint_time DESC
|
||||
LIMIT 100;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -29,4 +29,44 @@ This table contains comprehensive validator data by epoch, sourced from the Vali
|
||||
- `latitude` and `longitude`: Geographic coordinates of data center
|
||||
- `software_version`: Solana mainnet version
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Top validators by total stake with performance metrics
|
||||
```sql
|
||||
SELECT
|
||||
vote_pubkey,
|
||||
validator_name,
|
||||
SUM(active_stake) / pow(10,9) AS total_stake_sol,
|
||||
AVG(commission) AS avg_commission_pct,
|
||||
COUNT(DISTINCT epoch) AS epochs_active,
|
||||
MAX(epoch) AS last_active_epoch,
|
||||
AVG(CASE WHEN delinquent = FALSE THEN 1 ELSE 0 END) * 100 AS uptime_percentage
|
||||
FROM solana.gov.fact_validators
|
||||
WHERE epoch >= (SELECT MAX(epoch) - 10 FROM solana.gov.fact_validators)
|
||||
GROUP BY vote_pubkey, validator_name
|
||||
HAVING total_stake_sol > 10000
|
||||
ORDER BY total_stake_sol DESC
|
||||
LIMIT 50;
|
||||
```
|
||||
|
||||
|
||||
### Validator geographic distribution and performance
|
||||
```sql
|
||||
SELECT
|
||||
data_center_host,
|
||||
data_center_key,
|
||||
COUNT(DISTINCT vote_pubkey) AS validator_count,
|
||||
SUM(active_stake) / pow(10,9) AS total_stake_sol,
|
||||
AVG(commission) AS avg_commission,
|
||||
AVG(CASE WHEN delinquent = FALSE THEN 1 ELSE 0 END) * 100 AS avg_uptime_pct,
|
||||
COUNT(DISTINCT CASE WHEN delinquent = FALSE THEN vote_pubkey END) AS active_validators
|
||||
FROM solana.gov.fact_validators
|
||||
WHERE epoch = (SELECT MAX(epoch) FROM solana.gov.fact_validators)
|
||||
AND data_center_host IS NOT NULL
|
||||
GROUP BY data_center_host, data_center_key
|
||||
HAVING validator_count > 1
|
||||
ORDER BY total_stake_sol DESC
|
||||
LIMIT 50;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
@ -11,7 +11,6 @@ This table captures actions related to Marinade liquid staking, including deposi
|
||||
- Support liquid staking protocol performance analysis
|
||||
|
||||
## Important Relationships
|
||||
- Links to `silver.marinade_liquid_staking_actions` for detailed action data
|
||||
- Connects to `price.ez_prices_hourly` for USD price conversion
|
||||
- References `core.fact_blocks` and `core.fact_transactions` for blockchain context
|
||||
- Provides liquid staking context for Marinade Finance ecosystem analytics
|
||||
@ -23,4 +22,150 @@ This table captures actions related to Marinade liquid staking, including deposi
|
||||
- `deposit_amount` and `deposit_amount_usd`: Important for value analysis and financial metrics
|
||||
- `msol_minted` and `msol_burned`: Critical for MSOL token flow analysis
|
||||
|
||||
## Sample Queries
|
||||
|
||||
### Daily liquid staking deposits by protocol
|
||||
```sql
|
||||
-- Daily liquid staking deposits by protocol
|
||||
SELECT
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
'marinade' AS platform,
|
||||
COUNT(DISTINCT tx_id) AS deposit_txns,
|
||||
COUNT(DISTINCT provider_address) AS unique_stakers,
|
||||
SUM(deposit_amount) AS sol_staked,
|
||||
SUM(deposit_amount_usd) AS usd_staked,
|
||||
AVG(deposit_amount) AS avg_stake_size
|
||||
FROM solana.marinade.ez_liquid_staking_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 30
|
||||
AND action_type = 'deposit'
|
||||
AND deposit_amount_usd IS NOT NULL
|
||||
GROUP BY 1, 2
|
||||
ORDER BY 1 DESC, 6 DESC;
|
||||
```
|
||||
|
||||
### Protocol market share analysis
|
||||
```sql
|
||||
-- Protocol market share analysis
|
||||
WITH protocol_totals AS (
|
||||
SELECT
|
||||
'marinade' AS platform,
|
||||
SUM(deposit_amount) AS total_sol_staked,
|
||||
COUNT(DISTINCT provider_address) AS unique_stakers,
|
||||
COUNT(*) AS total_deposits
|
||||
FROM solana.marinade.ez_liquid_staking_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 90
|
||||
AND action_type = 'deposit'
|
||||
AND deposit_amount IS NOT NULL
|
||||
GROUP BY platform
|
||||
)
|
||||
SELECT
|
||||
platform,
|
||||
total_sol_staked,
|
||||
total_sol_staked * 100.0 / SUM(total_sol_staked) OVER () AS market_share_pct,
|
||||
unique_stakers,
|
||||
total_deposits,
|
||||
total_sol_staked / total_deposits AS avg_deposit_size
|
||||
FROM protocol_totals
|
||||
ORDER BY total_sol_staked DESC;
|
||||
```
|
||||
|
||||
### Staker behavior patterns
|
||||
```sql
|
||||
-- Staker behavior patterns
|
||||
WITH staker_activity AS (
|
||||
SELECT
|
||||
provider_address AS staker,
|
||||
COUNT(DISTINCT action_type) AS actions_used,
|
||||
COUNT(*) AS total_actions,
|
||||
SUM(CASE WHEN action_type = 'deposit' THEN deposit_amount ELSE 0 END) AS total_sol_staked,
|
||||
MIN(block_timestamp) AS first_stake,
|
||||
MAX(block_timestamp) AS last_stake,
|
||||
COUNT(DISTINCT DATE_TRUNC('month', block_timestamp)) AS active_months
|
||||
FROM solana.marinade.ez_liquid_staking_actions
|
||||
WHERE deposit_amount IS NOT NULL
|
||||
GROUP BY staker
|
||||
)
|
||||
SELECT
|
||||
CASE
|
||||
WHEN total_sol_staked < 1 THEN '< 1 SOL'
|
||||
WHEN total_sol_staked < 10 THEN '1-10 SOL'
|
||||
WHEN total_sol_staked < 32 THEN '10-32 SOL'
|
||||
WHEN total_sol_staked < 100 THEN '32-100 SOL'
|
||||
ELSE '100+ SOL'
|
||||
END AS staker_tier,
|
||||
COUNT(*) AS staker_count,
|
||||
AVG(total_actions) AS avg_actions_per_staker,
|
||||
AVG(actions_used) AS avg_action_types_used,
|
||||
SUM(total_sol_staked) AS tier_total_sol
|
||||
FROM staker_activity
|
||||
GROUP BY staker_tier
|
||||
ORDER BY MIN(total_sol_staked);
|
||||
```
|
||||
|
||||
### Exchange rate analysis (mSOL received per SOL)
|
||||
```sql
|
||||
-- Exchange rate analysis (mSOL received per SOL)
|
||||
SELECT
|
||||
'marinade' AS platform,
|
||||
'mSOL' AS token_symbol,
|
||||
DATE_TRUNC('day', block_timestamp) AS date,
|
||||
AVG(msol_minted / NULLIF(deposit_amount, 0)) AS avg_exchange_rate,
|
||||
MIN(msol_minted / NULLIF(deposit_amount, 0)) AS min_rate,
|
||||
MAX(msol_minted / NULLIF(deposit_amount, 0)) AS max_rate,
|
||||
COUNT(*) AS sample_size
|
||||
FROM solana.marinade.ez_liquid_staking_actions
|
||||
WHERE deposit_amount > 0
|
||||
AND msol_minted > 0
|
||||
AND action_type = 'deposit'
|
||||
AND block_timestamp >= CURRENT_DATE - 30
|
||||
GROUP BY 1, 2, 3
|
||||
ORDER BY 3 DESC;
|
||||
```
|
||||
|
||||
### Large deposits monitoring (whale activity)
|
||||
```sql
|
||||
-- Large deposits monitoring (whale activity)
|
||||
SELECT
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
'marinade' AS platform,
|
||||
provider_address AS staker,
|
||||
deposit_amount AS sol_amount,
|
||||
deposit_amount_usd AS sol_amount_usd,
|
||||
'mSOL' AS token_symbol,
|
||||
msol_minted AS token_amount,
|
||||
msol_minted / NULLIF(deposit_amount, 0) AS exchange_rate
|
||||
FROM solana.marinade.ez_liquid_staking_actions
|
||||
WHERE deposit_amount >= 100
|
||||
AND action_type = 'deposit'
|
||||
AND block_timestamp >= CURRENT_DATE - 7
|
||||
ORDER BY deposit_amount DESC;
|
||||
```
|
||||
|
||||
### Weekly staking momentum
|
||||
```sql
|
||||
-- Weekly staking momentum
|
||||
WITH weekly_deposits AS (
|
||||
SELECT
|
||||
DATE_TRUNC('week', block_timestamp) AS week,
|
||||
'marinade' AS platform,
|
||||
SUM(deposit_amount) AS weekly_sol_staked,
|
||||
COUNT(DISTINCT provider_address) AS unique_stakers
|
||||
FROM solana.marinade.ez_liquid_staking_actions
|
||||
WHERE block_timestamp >= CURRENT_DATE - 84
|
||||
AND action_type = 'deposit'
|
||||
AND deposit_amount IS NOT NULL
|
||||
GROUP BY 1, 2
|
||||
)
|
||||
SELECT
|
||||
week,
|
||||
platform,
|
||||
weekly_sol_staked,
|
||||
LAG(weekly_sol_staked) OVER (PARTITION BY platform ORDER BY week) AS prev_week_sol,
|
||||
(weekly_sol_staked / NULLIF(LAG(weekly_sol_staked) OVER (PARTITION BY platform ORDER BY week), 0) - 1) * 100 AS week_over_week_pct,
|
||||
unique_stakers
|
||||
FROM weekly_deposits
|
||||
ORDER BY week DESC, weekly_sol_staked DESC;
|
||||
```
|
||||
|
||||
{% enddocs %}
|
||||
Loading…
Reference in New Issue
Block a user