Skip to main content
Schema: ethereum.price Table: ez_prices_hourly Type: Base Table

What

This curated table provides reliable hourly price data for tokens and native assets across EVM blockchains. It combines multiple data sources with quality checks to ensure accurate, consistent pricing for DeFi analytics, portfolio valuations, and historical analysis.

Key Use Cases

  • Calculate USD values for token transfers and transaction amounts
  • Track price volatility and market movements over time
  • Monitor stablecoin depegging events and price stability
  • Analyze native asset price trends across different blockchains
  • Perform portfolio valuations and historical price lookups
  • Create price charts and technical analysis dashboards
  • Assess price data quality and imputation rates

Important Relationships

  • Join with ez_token_transfers: Calculate transfer USD values using hourly price snapshots
  • Join with ez_asset_metadata: Get token details and verification status
  • Join with dim_contracts: Match addresses with contract metadata

Commonly-used Fields

  • hour: UTC timestamp truncated to hour for price recording
  • token_address: Contract address of the token (NULL for native assets)
  • symbol: Token ticker symbol (ETH, USDC, etc.)
  • price: USD price of one whole token unit
  • is_imputed: Flag indicating forward-filled prices due to missing data
  • is_native: Boolean for blockchain native currencies
  • blockchain: Network where the asset exists

Sample Queries

Token Price Lookup with USD Calculations
-- Calculate USD value for token transfers
SELECT
    t.block_timestamp,
    t.tx_hash,
    t.symbol,
    t.from_address,
    t.to_address,
    t.amount,
    p.price,
    t.amount * p.price AS usd_value,
    p.is_imputed
FROM <blockchain_name>.core.ez_token_transfers t
JOIN <blockchain_name>.price.ez_prices_hourly p
    ON t.contract_address = p.token_address
    AND DATE_TRUNC('hour', t.block_timestamp) = p.hour
WHERE t.block_timestamp >= CURRENT_DATE - 7
    AND t.amount > 0
    AND p.price IS NOT NULL
ORDER BY usd_value DESC
LIMIT 100;
Price Volatility Analysis
-- 24-hour price volatility for major tokens
WITH price_stats AS (
    SELECT
        symbol,
        token_address,
        DATE(hour) AS date,
        MIN(price) AS daily_low,
        MAX(price) AS daily_high,
        AVG(price) AS daily_avg,
        STDDEV(price) AS daily_stddev,
        (MAX(price) - MIN(price)) / MIN(price) * 100 AS daily_range_pct
    FROM <blockchain_name>.price.ez_prices_hourly
    WHERE hour >= CURRENT_DATE - 30
        AND symbol IN ('WETH', 'USDC', 'USDT', 'WBTC', 'DAI')
        AND NOT is_imputed
    GROUP BY 1, 2, 3
)
SELECT
    symbol,
    AVG(daily_range_pct) AS avg_daily_volatility,
    MAX(daily_range_pct) AS max_daily_volatility,
    AVG(daily_stddev / daily_avg) * 100 AS avg_cv_pct
FROM price_stats
GROUP BY 1
ORDER BY 2 DESC;
Native Asset Price Tracking
-- Track native asset prices across chains
SELECT
    blockchain,
    symbol,
    hour,
    price,
    price / LAG(price, 24) OVER (PARTITION BY blockchain ORDER BY hour) - 1 AS change_24h,
    price / LAG(price, 168) OVER (PARTITION BY blockchain ORDER BY hour) - 1 AS change_7d
FROM <blockchain_name>.price.ez_prices_hourly
WHERE is_native = TRUE
    AND hour >= CURRENT_DATE - 8
    AND hour = DATE_TRUNC('hour', CURRENT_TIMESTAMP) - INTERVAL '1 hour'
ORDER BY blockchain;
Stablecoin Peg Monitoring
-- Monitor stablecoin deviations from $1
SELECT
    symbol,
    hour,
    price,
    ABS(price - 1.0) AS deviation,
    CASE
        WHEN ABS(price - 1.0) > 0.05 THEN 'Severe Depeg'
        WHEN ABS(price - 1.0) > 0.01 THEN 'Mild Depeg'
        ELSE 'Stable'
    END AS peg_status
FROM <blockchain_name>.price.ez_prices_hourly
WHERE symbol IN ('USDC', 'USDT', 'DAI', 'BUSD', 'FRAX', 'LUSD')
    AND hour >= CURRENT_DATE - 7
    AND ABS(price - 1.0) > 0.005
ORDER BY hour DESC, deviation DESC;
Price Data Quality Check
-- Analyze price data completeness and imputation rates
SELECT
    symbol,
    COUNT(*) AS total_hours,
    SUM(CASE WHEN is_imputed THEN 1 ELSE 0 END) AS imputed_hours,
    ROUND(100.0 * SUM(CASE WHEN is_imputed THEN 1 ELSE 0 END) / COUNT(*), 2) AS imputation_rate,
    MIN(hour) AS first_price,
    MAX(hour) AS last_price,
    COUNT(DISTINCT DATE(hour)) AS days_with_data
FROM <blockchain_name>.price.ez_prices_hourly
WHERE hour >= CURRENT_DATE - 30
GROUP BY 1
HAVING COUNT(*) > 100
ORDER BY imputation_rate DESC;

Columns

Column NameData TypeDescription
HOURTIMESTAMP_NTZUTC timestamp truncated to the hour for price recording. Used for joining with hourly transaction data.
Example: ‘2024-01-15 14:00:00.000’ | | TOKEN_ADDRESS | TEXT | Contract address of the token on the blockchain. NULL for native assets (ETH, AVAX, etc.). Example: ‘0xa0b86a33e6776a1e7f9f0b8b8b8b8b8b8b8b8b8b’ | | SYMBOL | TEXT | Token ticker symbol as commonly recognized. Usually 3-5 uppercase characters. Example: ‘WETH’ | | NAME | TEXT | | | DECIMALS | NUMBER | Number of decimal places for the token. Most ERC-20 tokens use 18 decimals, USDC/USDT use 6, WBTC uses 8. Example: 18 | | PRICE | FLOAT | USD price of one whole token unit at the recorded hour. Example: 3000.50 | | BLOCKCHAIN | TEXT | The blockchain network where the asset exists. Lowercase by convention. Example: ‘ethereum’ | | IS_NATIVE | BOOLEAN | Boolean indicating if the asset is the blockchain’s native currency. TRUE for ETH on Ethereum, AVAX on Avalanche, etc. Example: true | | IS_IMPUTED | BOOLEAN | Boolean flag indicating if the price was forward-filled due to missing data. TRUE means price carried forward from last known value. Example: false | | IS_DEPRECATED | BOOLEAN | Flag indicating if the asset is no longer actively supported. TRUE for deprecated assets that may have stale prices. Example: false | | IS_VERIFIED | BOOLEAN | Boolean indicating Flipside team verification of the asset. TRUE for manually verified assets with validated metadata. Example: true | | EZ_PRICES_HOURLY_ID | TEXT | Primary 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(block_number, tx_hash, 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_TIMESTAMP | TIMESTAMP_NTZ | UTC 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:
-- Check data latency
SELECT
    DATE_TRUNC('hour', block_timestamp) as block_hour,
    DATE_TRUNC('hour', inserted_timestamp) as insert_hour,
    AVG(TIMESTAMPDIFF('minute', block_timestamp, inserted_timestamp)) as avg_latency_minutes
FROM <blockchain_name>.core.fact_transactions
WHERE block_timestamp >= CURRENT_DATE - 1
GROUP BY 1, 2;
``` |
| MODIFIED_TIMESTAMP | TIMESTAMP_NTZ | UTC 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**:
```sql
-- Recently modified records
SELECT *
FROM <blockchain_name>.core.fact_transactions
WHERE modified_timestamp > inserted_timestamp
AND modified_timestamp >= CURRENT_DATE - 1;

-- Data quality tracking
SELECT
    DATE(modified_timestamp) as mod_date,
    COUNT(*) as records_updated,
    COUNT(DISTINCT block_number) as blocks_affected
FROM <blockchain_name>.core.fact_transactions
WHERE modified_timestamp > inserted_timestamp
GROUP BY 1
ORDER BY 1 DESC;
``` |