-- Hyperliquid Wallet Tracker Database Schema -- Create database (uncomment if needed) CREATE DATABASE IF NOT EXISTS hyperliquid_tracker CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; USE hyperliquid_tracker; -- Wallets table to store tracked wallet addresses CREATE TABLE IF NOT EXISTS wallets ( id INT AUTO_INCREMENT PRIMARY KEY, address VARCHAR(66) NOT NULL UNIQUE COMMENT 'Wallet address (normalized to lowercase)', first_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT 'When this wallet was first tracked', last_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT 'Last time this wallet was seen in trades', trade_count INT DEFAULT 1 COMMENT 'Number of times this wallet has been seen in trades', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, INDEX idx_address (address), INDEX idx_last_seen (last_seen_at), INDEX idx_trade_count (trade_count) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Tracked wallet addresses from Hyperliquid trades'; -- Wallet PnL snapshots table (optional - for historical tracking) CREATE TABLE IF NOT EXISTS wallet_pnl_snapshots ( id INT AUTO_INCREMENT PRIMARY KEY, wallet_id INT NOT NULL, wallet_address VARCHAR(66) NOT NULL, pnl DECIMAL(30, 8) COMMENT 'Profit and Loss value', account_value DECIMAL(30, 8) COMMENT 'Total account value', unrealized_pnl DECIMAL(30, 8) COMMENT 'Unrealized PnL', snapshot_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (wallet_id) REFERENCES wallets(id) ON DELETE CASCADE, INDEX idx_wallet_id (wallet_id), INDEX idx_wallet_address (wallet_address), INDEX idx_snapshot_at (snapshot_at) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Historical PnL snapshots for tracked wallets'; -- View for wallets with latest PnL CREATE OR REPLACE VIEW wallets_with_latest_pnl AS SELECT w.id, w.address, w.first_seen_at, w.last_seen_at, w.trade_count, wps.pnl, wps.account_value, wps.unrealized_pnl, wps.snapshot_at as last_pnl_snapshot FROM wallets w LEFT JOIN wallet_pnl_snapshots wps ON w.id = wps.wallet_id LEFT JOIN ( SELECT wallet_id, MAX(snapshot_at) as max_snapshot FROM wallet_pnl_snapshots GROUP BY wallet_id ) latest ON w.id = latest.wallet_id AND wps.snapshot_at = latest.max_snapshot;