-- 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'; -- Note: PnL is now calculated from trades table, so wallet_pnl_snapshots table is no longer used -- Trades table to store individual trades for each wallet CREATE TABLE IF NOT EXISTS trades ( id INT AUTO_INCREMENT PRIMARY KEY, wallet_id INT NOT NULL, wallet_address VARCHAR(66) NOT NULL, entry_hash VARCHAR(66) NOT NULL UNIQUE COMMENT 'Unique identifier for the trade entry (transaction hash)', entry_date TIMESTAMP NULL COMMENT 'When the position was opened', close_date TIMESTAMP NULL COMMENT 'When the position was closed (NULL if still open)', coin VARCHAR(20) NOT NULL COMMENT 'Trading pair/coin symbol', amount DECIMAL(30, 8) NOT NULL COMMENT 'Trade size/amount', entry_price DECIMAL(30, 8) NOT NULL COMMENT 'Price when position was opened', close_price DECIMAL(30, 8) NULL COMMENT 'Price when position was closed (NULL if still open)', direction ENUM('buy', 'sell') NOT NULL DEFAULT 'buy' COMMENT 'Trade direction: buy or sell', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE 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_entry_hash (entry_hash), INDEX idx_coin (coin), INDEX idx_entry_date (entry_date), INDEX idx_close_date (close_date), INDEX idx_direction (direction) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Individual trades for tracked wallets'; -- Migration: Add direction column if it doesn't exist ALTER TABLE trades ADD COLUMN IF NOT EXISTS direction ENUM('buy', 'sell') NOT NULL DEFAULT 'buy' COMMENT 'Trade direction: buy or sell' AFTER close_price; ALTER TABLE trades ADD INDEX IF NOT EXISTS idx_direction (direction); -- Note: PnL is now calculated on-demand from trades table, so the view is no longer needed