93 lines
5.7 KiB
SQL
93 lines
5.7 KiB
SQL
-- 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
|
|
|
|
-- Trade history table to store historical trades fetched from Hyperliquid API
|
|
CREATE TABLE IF NOT EXISTS trade_history (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
wallet_id INT NOT NULL,
|
|
wallet_address VARCHAR(66) NOT NULL COMMENT 'Wallet address (normalized to lowercase)',
|
|
trade_id VARCHAR(255) NOT NULL COMMENT 'Unique trade ID from Hyperliquid',
|
|
coin VARCHAR(20) NOT NULL COMMENT 'Trading pair/coin symbol',
|
|
side ENUM('buy', 'sell') NOT NULL COMMENT 'Trade side: buy or sell',
|
|
size DECIMAL(30, 8) NOT NULL COMMENT 'Trade size/amount',
|
|
price DECIMAL(30, 8) NOT NULL COMMENT 'Execution price (fill price)',
|
|
entry_price DECIMAL(30, 8) NULL COMMENT 'Entry price for position (calculated from fills)',
|
|
close_price DECIMAL(30, 8) NULL COMMENT 'Close price for position (calculated from fills)',
|
|
closed_pnl DECIMAL(30, 8) NULL COMMENT 'Realized PnL from closing this position (from API)',
|
|
fee DECIMAL(30, 8) DEFAULT 0 COMMENT 'Fee paid',
|
|
timestamp TIMESTAMP NOT NULL COMMENT 'Time trade executed',
|
|
order_type VARCHAR(50) NULL COMMENT 'Order type: market, limit, trigger, etc',
|
|
status VARCHAR(50) NULL COMMENT 'Order status: filled, cancelled, open, etc',
|
|
extra_data JSON NULL COMMENT 'Additional data from API (liquidation, builder fees, etc)',
|
|
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,
|
|
UNIQUE KEY unique_trade (wallet_address, trade_id),
|
|
INDEX idx_wallet_id (wallet_id),
|
|
INDEX idx_wallet_address (wallet_address),
|
|
INDEX idx_trade_id (trade_id),
|
|
INDEX idx_coin (coin),
|
|
INDEX idx_timestamp (timestamp),
|
|
INDEX idx_side (side)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Historical trades fetched from Hyperliquid API';
|
|
|
|
-- Migration: Add entry_price and close_price columns if they don't exist
|
|
ALTER TABLE trade_history ADD COLUMN IF NOT EXISTS entry_price DECIMAL(30, 8) NULL COMMENT 'Entry price for position (calculated from fills)' AFTER price;
|
|
ALTER TABLE trade_history ADD COLUMN IF NOT EXISTS close_price DECIMAL(30, 8) NULL COMMENT 'Close price for position (calculated from fills)' AFTER entry_price;
|
|
ALTER TABLE trade_history ADD COLUMN IF NOT EXISTS closed_pnl DECIMAL(30, 8) NULL COMMENT 'Realized PnL from closing this position (from API)' AFTER close_price;
|
|
|
|
-- Add column to wallets to track last trade fetch time for rate limiting
|
|
ALTER TABLE wallets ADD COLUMN IF NOT EXISTS last_trade_fetch_at TIMESTAMP NULL COMMENT 'Last time historical trades were fetched for this wallet' AFTER last_seen_at;
|
|
ALTER TABLE wallets ADD INDEX IF NOT EXISTS idx_last_trade_fetch (last_trade_fetch_at);
|
|
|