Skip to main content
Schema: somnia.core Table: ez_native_transfers Type: Base Table

What

This convenience table tracks all native asset transfers (ETH, AVAX, MATIC, etc.) extracted from transaction traces. It provides a simplified view of value movements with decimal adjustments and USD conversions, making it easy to analyze fund flows without parsing complex trace data.

Key Use Cases

  • Tracking native asset movements between wallets and contracts
  • Analyzing exchange deposits and withdrawals
  • Monitoring whale movements and large transfers
  • Calculating wallet balances from transfer history
  • Identifying internal transfers within smart contract executions

Important Relationships

  • Join with fact_transactions: Use tx_hash for transaction context
  • Join with fact_traces: Use tx_hash and trace_index for trace details
  • Join with dim_labels: Use addresses for entity identification
  • Complement to ez_token_transfers: This table for native, that for tokens

Commonly-used Fields

  • from_address: The sender of the native asset transfer
  • to_address: The recipient of the native asset transfer
  • amount: Decimal-adjusted transfer amount
  • amount_usd: USD value at time of transfer
  • origin_from_address: Original transaction sender
  • origin_to_address: Original transaction recipient
  • identifier: Trace identifier (0 for external transfers)

Sample queries

Daily Native Asset Transfer Volume
SELECT 
    DATE_TRUNC('day', block_timestamp) AS day,
    COUNT(*) AS transfer_count,
    COUNT(DISTINCT from_address) AS unique_senders,
    COUNT(DISTINCT to_address) AS unique_receivers,
    SUM(amount) AS total_amount,
    AVG(amount) AS avg_amount,
    SUM(amount_usd) AS total_usd,
    MAX(amount_usd) AS largest_transfer_usd
FROM <blockchain_name>.core.ez_native_transfers
WHERE block_timestamp >= CURRENT_DATE - 30
    AND amount > 0
GROUP BY 1
ORDER BY 1 DESC;
Whale Movements (Large Transfers)
SELECT 
    block_timestamp,
    tx_hash,
    from_address,
    to_address,
    amount,
    amount_usd,
    origin_from_address,
    origin_to_address,
    identifier
FROM <blockchain_name>.core.ez_native_transfers
WHERE amount_usd > 1000000  -- Over $1M USD
    AND block_timestamp >= CURRENT_DATE - 7
ORDER BY amount_usd DESC
LIMIT 100;
Exchange Deposit/Withdrawal Patterns
WITH exchange_addresses AS (
    SELECT DISTINCT address 
    FROM dim_labels 
    WHERE label_type = 'exchange'
)
SELECT 
    DATE_TRUNC('hour', block_timestamp) AS hour,
    CASE 
        WHEN to_address IN (SELECT address FROM exchange_addresses) THEN 'Deposit'
        WHEN from_address IN (SELECT address FROM exchange_addresses) THEN 'Withdrawal'
    END AS transfer_type,
    COUNT(*) AS transfer_count,
    SUM(amount) AS total_amount,
    SUM(amount_usd) AS total_usd
FROM <blockchain_name>.core.ez_native_transfers
WHERE block_timestamp >= CURRENT_DATE - 1
    AND (to_address IN (SELECT address FROM exchange_addresses)
         OR from_address IN (SELECT address FROM exchange_addresses))
GROUP BY 1, 2
ORDER BY 1 DESC;
Internal Transfer Analysis
-- Compare external vs internal transfers
SELECT 
    CASE 
        WHEN identifier = '0' THEN 'External Transfer'
        ELSE 'Internal Transfer'
    END AS transfer_type,
    COUNT(*) AS count,
    SUM(amount) AS total_amount,
    AVG(amount) AS avg_amount,
    SUM(amount_usd) AS total_volume_usd
FROM <blockchain_name>.core.ez_native_transfers
WHERE block_timestamp >= CURRENT_DATE - 1
GROUP BY 1;
Smart Contract Native Asset Holdings
WITH contract_balances AS (
    SELECT 
        to_address AS address,
        SUM(amount) AS inflows
    FROM <blockchain_name>.core.ez_native_transfers
    WHERE to_address IN (SELECT address FROM dim_contracts)
    GROUP BY 1
),
outflows AS (
    SELECT 
        from_address AS address,
        SUM(amount) AS outflows
    FROM <blockchain_name>.core.ez_native_transfers
    WHERE from_address IN (SELECT address FROM dim_contracts)
    GROUP BY 1
)
SELECT 
    c.address,
    dc.name AS contract_name,
    COALESCE(c.inflows, 0) - COALESCE(o.outflows, 0) AS net_balance,
    c.inflows,
    o.outflows
FROM contract_balances c
LEFT JOIN outflows o ON c.address = o.address
LEFT JOIN <blockchain_name>.core.dim_contracts dc ON c.address = dc.address
WHERE COALESCE(c.inflows, 0) - COALESCE(o.outflows, 0) > 100  -- Over 100 native tokens
ORDER BY net_balance DESC
LIMIT 50;

Columns

Column NameData TypeDescription
BLOCK_NUMBERNUMBERSequential counter representing the position of a block in the blockchain since genesis (block 0). Key Facts: Immutable once finalized Primary ordering mechanism for blockchain data Increments by 1 for each new block Used as a proxy for time in many analyses Usage in Queries: Important: Block numbers are chain-specific. Block 15000000 on Ethereum ≠ block 15000000 on Polygon.
BLOCK_TIMESTAMPTIMESTAMP_NTZUTC timestamp when the block was produced by validators/miners. Format: TIMESTAMP_NTZ (no timezone) Precision: Second-level accuracy Reliability: Set by block producer Can have minor variations (±15 seconds) Always increasing (newer blocks = later timestamps) Best Practices: Note: Use for time-series analysis, but be aware that block production rates vary by chain.
TX_HASHTEXTUnique 66-character identifier for the transaction. Format: 0x + 64 hexadecimal characters Usage: Primary key for transaction lookups Join key for traces, logs, and token transfers Immutable once confirmed Example: 0x5c504ed432cb51138bcf09aa5e8a410dd4a1e204ef84bfed1be16dfba1b22060
TX_POSITIONNUMBERZero-indexed position of transaction within its block. Insights: Position 0: First transaction in block MEV bots often target early positions Bundle transactions appear consecutively Useful for analyzing transaction ordering
TRACE_INDEXNUMBERSequential index of trace within the transaction’s execution. Example: 3
TRACE_ADDRESSTEXTArray describing the trace’s position in the execution tree. Example: [0, 1, 2]
TYPETEXTThe type of EVM operation performed. Example: ‘CALL’
FROM_ADDRESSTEXTThe from address for the native asset transfer. This may or may not be the same as the originfromaddress. Example: ‘0x1234567890123456789012345678901234567890’
TO_ADDRESSTEXTThe to address for the native asset transfer. This may or may not be the same as the origintoaddress. Example: ‘0xabcdefabcdefabcdefabcdefabcdefabcdefabcd’
AMOUNTFLOATNative asset amount transferred, adjusted to standard decimal units. Example: 1.5
AMOUNT_PRECISE_RAWTEXTNative asset amount transferred, no decimal adjustment, returned as a string to preserve precision. Example: ‘1500000000000000000’
AMOUNT_PRECISETEXTNative asset amount transferred, decimal adjusted, returned as a string to preserve precision. Example: ‘1.500000000000000000’
AMOUNT_USDFLOATUSD value of the native asset transfer at the time of the transaction. Example: 2500.50
ORIGIN_FROM_ADDRESSTEXTThe externally-owned account (EOA) or contract address that initiated the transaction. Key Points: Always 42 characters (0x + 40 hex chars) Lowercase normalized in all tables Cannot be NULL for valid transactions For contract creation: sender of creation transaction Common Patterns: EOA → EOA: Simple transfer EOA → Contract: User interaction Contract → Contract: Internal calls (see fact_traces) Known addresses: Exchange hot wallets, protocol deployers Query Examples:
ORIGIN_TO_ADDRESSTEXTThe destination address for the transaction - either an EOA or contract address. Special Cases: NULL: Contract creation transaction Contract address: Interacting with smart contract EOA address: Simple transfer or receiving funds Important Patterns: Note: For token transfers, this is the token contract, not the recipient. See eztokentransfers tables for recipient.
ORIGIN_FUNCTION_SIGNATURETEXTFunction signature (first 4 bytes) of the called method. Format: 0x + 8 hex characters Common Signatures: 0xa9059cbb: transfer(address,uint256) 0x095ea7b3: approve(address,uint256) 0x23b872dd: transferFrom(address,address,uint256) Note: NULL for simple transfers or invalid calls
EZ_NATIVE_TRANSFERS_IDTEXTPrimary key - unique identifier for each row ensuring data integrity. Format: Usually VARCHAR containing composite key generated using MD5 hash of the relevant columns. Example: MD5(blocknumber, txhash, trace_index) Usage: Deduplication in incremental loads Join operations for data quality checks Troubleshooting specific records Important: Implementation varies by table - check table-specific documentation.
INSERTED_TIMESTAMPTIMESTAMP_NTZUTC timestamp when the record was first added to the Flipside database. Format: TIMESTAMP_NTZ Use Cases: Data freshness monitoring Incremental processing markers Debugging data pipeline issues SLA tracking Query Example:
MODIFIED_TIMESTAMPTIMESTAMP_NTZUTC timestamp of the most recent update to this record. Format: TIMESTAMP_NTZ Triggers for Updates: Data corrections Enrichment additions Reprocessing for accuracy Schema migrations Monitoring Usage: