Update database schema and configuration for Crypto Trading Bot Platform
- Added new SQLAlchemy models in `database/models.py` for market data, trades, bots, signals, and performance tracking. - Updated `docker-compose.yml` to use TimescaleDB for PostgreSQL and configured shared preload libraries. - Created new schema files: `schema.sql` for the complete database setup and `schema_clean.sql` for a simplified version without hypertables. - Updated documentation in `setup.md` to reflect changes in database initialization and service setup.
This commit is contained in:
parent
692611d3ae
commit
8121ce0430
1
.gitignore
vendored
1
.gitignore
vendored
@ -1,3 +1,4 @@
|
|||||||
*.pyc
|
*.pyc
|
||||||
.env
|
.env
|
||||||
.env.local
|
.env.local
|
||||||
|
.env.*
|
||||||
|
|||||||
@ -21,4 +21,7 @@ GRANT ALL PRIVILEGES ON DATABASE dashboard TO dashboard;
|
|||||||
GRANT ALL ON SCHEMA public TO dashboard;
|
GRANT ALL ON SCHEMA public TO dashboard;
|
||||||
|
|
||||||
-- Create initial comment
|
-- Create initial comment
|
||||||
COMMENT ON DATABASE dashboard IS 'Crypto Trading Bot Dashboard Database';
|
COMMENT ON DATABASE dashboard IS 'Crypto Trading Bot Dashboard Database';
|
||||||
|
|
||||||
|
-- Execute the main schema file
|
||||||
|
\i /docker-entrypoint-initdb.d/schema.sql
|
||||||
329
database/init/schema.sql
Normal file
329
database/init/schema.sql
Normal file
@ -0,0 +1,329 @@
|
|||||||
|
-- Database Schema for Crypto Trading Bot Platform
|
||||||
|
-- Following PRD specifications with optimized schema for time-series data
|
||||||
|
-- Version: 1.0
|
||||||
|
-- Author: Generated following PRD requirements
|
||||||
|
|
||||||
|
-- Create extensions
|
||||||
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||||
|
CREATE EXTENSION IF NOT EXISTS "timescaledb" CASCADE;
|
||||||
|
|
||||||
|
-- Set timezone to UTC for consistency
|
||||||
|
SET timezone = 'UTC';
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- MARKET DATA TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- OHLCV Market Data (primary table for bot operations)
|
||||||
|
-- This is the main table that bots will use for trading decisions
|
||||||
|
CREATE TABLE market_data (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
exchange VARCHAR(50) NOT NULL DEFAULT 'okx',
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timeframe VARCHAR(5) NOT NULL, -- 1m, 5m, 15m, 1h, 4h, 1d
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
open DECIMAL(18,8) NOT NULL,
|
||||||
|
high DECIMAL(18,8) NOT NULL,
|
||||||
|
low DECIMAL(18,8) NOT NULL,
|
||||||
|
close DECIMAL(18,8) NOT NULL,
|
||||||
|
volume DECIMAL(18,8) NOT NULL,
|
||||||
|
trades_count INTEGER, -- number of trades in this candle
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT unique_market_data UNIQUE(exchange, symbol, timeframe, timestamp)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('market_data', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Create optimized indexes for market data
|
||||||
|
CREATE INDEX idx_market_data_lookup ON market_data(symbol, timeframe, timestamp);
|
||||||
|
CREATE INDEX idx_market_data_recent ON market_data(timestamp DESC) WHERE timestamp > NOW() - INTERVAL '7 days';
|
||||||
|
CREATE INDEX idx_market_data_symbol ON market_data(symbol);
|
||||||
|
CREATE INDEX idx_market_data_timeframe ON market_data(timeframe);
|
||||||
|
|
||||||
|
-- Raw Trade Data (optional, for detailed backtesting only)
|
||||||
|
-- This table is partitioned by timestamp for better performance
|
||||||
|
CREATE TABLE raw_trades (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
exchange VARCHAR(50) NOT NULL DEFAULT 'okx',
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
type VARCHAR(10) NOT NULL, -- trade, order, balance, tick, books
|
||||||
|
data JSONB NOT NULL, -- response from the exchange
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW()
|
||||||
|
) PARTITION BY RANGE (timestamp);
|
||||||
|
|
||||||
|
-- Create initial partition for current month
|
||||||
|
CREATE TABLE raw_trades_current PARTITION OF raw_trades
|
||||||
|
FOR VALUES FROM (date_trunc('month', NOW())) TO (date_trunc('month', NOW()) + INTERVAL '1 month');
|
||||||
|
|
||||||
|
-- Index for raw trades
|
||||||
|
CREATE INDEX idx_raw_trades_symbol_time ON raw_trades(symbol, timestamp);
|
||||||
|
CREATE INDEX idx_raw_trades_type ON raw_trades(type);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- BOT MANAGEMENT TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Bot Management (simplified)
|
||||||
|
CREATE TABLE bots (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
name VARCHAR(100) NOT NULL,
|
||||||
|
strategy_name VARCHAR(50) NOT NULL,
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timeframe VARCHAR(5) NOT NULL,
|
||||||
|
status VARCHAR(20) NOT NULL DEFAULT 'inactive', -- active, inactive, error, paused
|
||||||
|
config_file VARCHAR(200), -- path to JSON config
|
||||||
|
virtual_balance DECIMAL(18,8) DEFAULT 10000,
|
||||||
|
current_balance DECIMAL(18,8) DEFAULT 10000,
|
||||||
|
last_heartbeat TIMESTAMPTZ,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_bot_status CHECK (status IN ('active', 'inactive', 'error', 'paused'))
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Indexes for bot management
|
||||||
|
CREATE INDEX idx_bots_status ON bots(status);
|
||||||
|
CREATE INDEX idx_bots_symbol ON bots(symbol);
|
||||||
|
CREATE INDEX idx_bots_strategy ON bots(strategy_name);
|
||||||
|
CREATE INDEX idx_bots_last_heartbeat ON bots(last_heartbeat);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- TRADING SIGNAL TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Trading Signals (for analysis and debugging)
|
||||||
|
CREATE TABLE signals (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
signal_type VARCHAR(10) NOT NULL, -- buy, sell, hold
|
||||||
|
price DECIMAL(18,8),
|
||||||
|
confidence DECIMAL(5,4), -- signal confidence score (0.0000 to 1.0000)
|
||||||
|
indicators JSONB, -- technical indicator values
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_signal_type CHECK (signal_type IN ('buy', 'sell', 'hold')),
|
||||||
|
CONSTRAINT chk_confidence CHECK (confidence >= 0 AND confidence <= 1)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert signals to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('signals', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Indexes for signals
|
||||||
|
CREATE INDEX idx_signals_bot_time ON signals(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_signals_type ON signals(signal_type);
|
||||||
|
CREATE INDEX idx_signals_timestamp ON signals(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- TRADE EXECUTION TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Trade Execution Records
|
||||||
|
CREATE TABLE trades (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
signal_id INTEGER REFERENCES signals(id) ON DELETE SET NULL,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
side VARCHAR(5) NOT NULL, -- buy, sell
|
||||||
|
price DECIMAL(18,8) NOT NULL,
|
||||||
|
quantity DECIMAL(18,8) NOT NULL,
|
||||||
|
fees DECIMAL(18,8) DEFAULT 0,
|
||||||
|
pnl DECIMAL(18,8), -- profit/loss for this trade
|
||||||
|
balance_after DECIMAL(18,8), -- portfolio balance after trade
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_trade_side CHECK (side IN ('buy', 'sell')),
|
||||||
|
CONSTRAINT chk_positive_price CHECK (price > 0),
|
||||||
|
CONSTRAINT chk_positive_quantity CHECK (quantity > 0),
|
||||||
|
CONSTRAINT chk_non_negative_fees CHECK (fees >= 0)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert trades to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('trades', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Indexes for trades
|
||||||
|
CREATE INDEX idx_trades_bot_time ON trades(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_trades_side ON trades(side);
|
||||||
|
CREATE INDEX idx_trades_timestamp ON trades(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- PERFORMANCE TRACKING TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Performance Snapshots (for plotting portfolio over time)
|
||||||
|
CREATE TABLE bot_performance (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
total_value DECIMAL(18,8) NOT NULL, -- current portfolio value
|
||||||
|
cash_balance DECIMAL(18,8) NOT NULL,
|
||||||
|
crypto_balance DECIMAL(18,8) NOT NULL,
|
||||||
|
total_trades INTEGER DEFAULT 0,
|
||||||
|
winning_trades INTEGER DEFAULT 0,
|
||||||
|
total_fees DECIMAL(18,8) DEFAULT 0,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_non_negative_values CHECK (
|
||||||
|
total_value >= 0 AND
|
||||||
|
cash_balance >= 0 AND
|
||||||
|
crypto_balance >= 0 AND
|
||||||
|
total_trades >= 0 AND
|
||||||
|
winning_trades >= 0 AND
|
||||||
|
total_fees >= 0
|
||||||
|
),
|
||||||
|
CONSTRAINT chk_winning_trades_logic CHECK (winning_trades <= total_trades)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert bot_performance to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('bot_performance', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Indexes for bot performance
|
||||||
|
CREATE INDEX idx_bot_performance_bot_time ON bot_performance(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_bot_performance_timestamp ON bot_performance(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- FUNCTIONS AND TRIGGERS
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Function to update bot updated_at timestamp
|
||||||
|
CREATE OR REPLACE FUNCTION update_bot_timestamp()
|
||||||
|
RETURNS TRIGGER AS $$
|
||||||
|
BEGIN
|
||||||
|
NEW.updated_at = NOW();
|
||||||
|
RETURN NEW;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- Trigger to automatically update bot updated_at
|
||||||
|
CREATE TRIGGER trigger_update_bot_timestamp
|
||||||
|
BEFORE UPDATE ON bots
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE FUNCTION update_bot_timestamp();
|
||||||
|
|
||||||
|
-- Function to create monthly partition for raw_trades
|
||||||
|
CREATE OR REPLACE FUNCTION create_monthly_partition_for_raw_trades(partition_date DATE)
|
||||||
|
RETURNS VOID AS $$
|
||||||
|
DECLARE
|
||||||
|
partition_name TEXT;
|
||||||
|
start_date DATE;
|
||||||
|
end_date DATE;
|
||||||
|
BEGIN
|
||||||
|
start_date := date_trunc('month', partition_date);
|
||||||
|
end_date := start_date + INTERVAL '1 month';
|
||||||
|
partition_name := 'raw_trades_' || to_char(start_date, 'YYYY_MM');
|
||||||
|
|
||||||
|
EXECUTE format('CREATE TABLE IF NOT EXISTS %I PARTITION OF raw_trades
|
||||||
|
FOR VALUES FROM (%L) TO (%L)',
|
||||||
|
partition_name, start_date, end_date);
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- VIEWS FOR COMMON QUERIES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- View for bot status overview
|
||||||
|
CREATE VIEW bot_status_overview AS
|
||||||
|
SELECT
|
||||||
|
b.id,
|
||||||
|
b.name,
|
||||||
|
b.strategy_name,
|
||||||
|
b.symbol,
|
||||||
|
b.status,
|
||||||
|
b.current_balance,
|
||||||
|
b.virtual_balance,
|
||||||
|
(b.current_balance - b.virtual_balance) as pnl,
|
||||||
|
b.last_heartbeat,
|
||||||
|
COUNT(t.id) as total_trades,
|
||||||
|
COALESCE(SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END), 0) as winning_trades
|
||||||
|
FROM bots b
|
||||||
|
LEFT JOIN trades t ON b.id = t.bot_id
|
||||||
|
GROUP BY b.id, b.name, b.strategy_name, b.symbol, b.status,
|
||||||
|
b.current_balance, b.virtual_balance, b.last_heartbeat;
|
||||||
|
|
||||||
|
-- View for recent market data
|
||||||
|
CREATE VIEW recent_market_data AS
|
||||||
|
SELECT
|
||||||
|
symbol,
|
||||||
|
timeframe,
|
||||||
|
timestamp,
|
||||||
|
open,
|
||||||
|
high,
|
||||||
|
low,
|
||||||
|
close,
|
||||||
|
volume,
|
||||||
|
trades_count
|
||||||
|
FROM market_data
|
||||||
|
WHERE timestamp > NOW() - INTERVAL '24 hours'
|
||||||
|
ORDER BY symbol, timeframe, timestamp DESC;
|
||||||
|
|
||||||
|
-- View for trading performance summary
|
||||||
|
CREATE VIEW trading_performance_summary AS
|
||||||
|
SELECT
|
||||||
|
t.bot_id,
|
||||||
|
b.name as bot_name,
|
||||||
|
COUNT(t.id) as total_trades,
|
||||||
|
SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END) as winning_trades,
|
||||||
|
ROUND((SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END)::DECIMAL / COUNT(t.id)) * 100, 2) as win_rate_percent,
|
||||||
|
ROUND(SUM(t.pnl), 4) as total_pnl,
|
||||||
|
ROUND(SUM(t.fees), 4) as total_fees,
|
||||||
|
MIN(t.timestamp) as first_trade,
|
||||||
|
MAX(t.timestamp) as last_trade
|
||||||
|
FROM trades t
|
||||||
|
JOIN bots b ON t.bot_id = b.id
|
||||||
|
GROUP BY t.bot_id, b.name
|
||||||
|
ORDER BY total_pnl DESC;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- INITIAL DATA SEEDING
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Insert sample timeframes that the system supports
|
||||||
|
CREATE TABLE IF NOT EXISTS supported_timeframes (
|
||||||
|
timeframe VARCHAR(5) PRIMARY KEY,
|
||||||
|
description VARCHAR(50),
|
||||||
|
minutes INTEGER
|
||||||
|
);
|
||||||
|
|
||||||
|
INSERT INTO supported_timeframes (timeframe, description, minutes) VALUES
|
||||||
|
('1m', '1 Minute', 1),
|
||||||
|
('5m', '5 Minutes', 5),
|
||||||
|
('15m', '15 Minutes', 15),
|
||||||
|
('1h', '1 Hour', 60),
|
||||||
|
('4h', '4 Hours', 240),
|
||||||
|
('1d', '1 Day', 1440)
|
||||||
|
ON CONFLICT (timeframe) DO NOTHING;
|
||||||
|
|
||||||
|
-- Insert sample exchanges
|
||||||
|
CREATE TABLE IF NOT EXISTS supported_exchanges (
|
||||||
|
exchange VARCHAR(50) PRIMARY KEY,
|
||||||
|
name VARCHAR(100),
|
||||||
|
api_url VARCHAR(200),
|
||||||
|
enabled BOOLEAN DEFAULT true
|
||||||
|
);
|
||||||
|
|
||||||
|
INSERT INTO supported_exchanges (exchange, name, api_url, enabled) VALUES
|
||||||
|
('okx', 'OKX Exchange', 'https://www.okx.com/api/v5', true),
|
||||||
|
('binance', 'Binance Exchange', 'https://api.binance.com/api/v3', false),
|
||||||
|
('coinbase', 'Coinbase Pro', 'https://api.exchange.coinbase.com', false)
|
||||||
|
ON CONFLICT (exchange) DO NOTHING;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- COMMENTS FOR DOCUMENTATION
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
COMMENT ON TABLE market_data IS 'Primary OHLCV market data table optimized for bot operations and backtesting';
|
||||||
|
COMMENT ON TABLE raw_trades IS 'Optional raw trade data for detailed backtesting (partitioned by month)';
|
||||||
|
COMMENT ON TABLE bots IS 'Bot instance management with JSON configuration references';
|
||||||
|
COMMENT ON TABLE signals IS 'Trading signals generated by strategies with confidence scores';
|
||||||
|
COMMENT ON TABLE trades IS 'Virtual trade execution records with P&L tracking';
|
||||||
|
COMMENT ON TABLE bot_performance IS 'Portfolio performance snapshots for visualization';
|
||||||
|
|
||||||
|
COMMENT ON COLUMN market_data.timestamp IS 'Right-aligned timestamp (candle close time) following exchange standards';
|
||||||
|
COMMENT ON COLUMN bots.config_file IS 'Path to JSON configuration file for strategy parameters';
|
||||||
|
COMMENT ON COLUMN signals.confidence IS 'Signal confidence score from 0.0000 to 1.0000';
|
||||||
|
COMMENT ON COLUMN trades.pnl IS 'Profit/Loss for this specific trade in base currency';
|
||||||
|
COMMENT ON COLUMN bot_performance.total_value IS 'Current total portfolio value (cash + crypto)';
|
||||||
|
|
||||||
|
-- Grant permissions to dashboard user
|
||||||
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO dashboard;
|
||||||
|
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO dashboard;
|
||||||
|
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO dashboard;
|
||||||
291
database/models.py
Normal file
291
database/models.py
Normal file
@ -0,0 +1,291 @@
|
|||||||
|
"""
|
||||||
|
Database Models for Crypto Trading Bot Platform
|
||||||
|
SQLAlchemy models corresponding to the database schema
|
||||||
|
"""
|
||||||
|
|
||||||
|
from datetime import datetime
|
||||||
|
from decimal import Decimal
|
||||||
|
from typing import Optional, Dict, Any
|
||||||
|
|
||||||
|
from sqlalchemy import (
|
||||||
|
Boolean, Column, DateTime, ForeignKey, Integer,
|
||||||
|
String, Text, DECIMAL, JSON, Index, CheckConstraint,
|
||||||
|
UniqueConstraint, text
|
||||||
|
)
|
||||||
|
from sqlalchemy.ext.declarative import declarative_base
|
||||||
|
from sqlalchemy.orm import relationship
|
||||||
|
from sqlalchemy.sql import func
|
||||||
|
|
||||||
|
# Create base class for all models
|
||||||
|
Base = declarative_base()
|
||||||
|
|
||||||
|
|
||||||
|
class MarketData(Base):
|
||||||
|
"""OHLCV Market Data - Primary table for bot operations"""
|
||||||
|
__tablename__ = 'market_data'
|
||||||
|
|
||||||
|
id = Column(Integer, primary_key=True)
|
||||||
|
exchange = Column(String(50), nullable=False, default='okx')
|
||||||
|
symbol = Column(String(20), nullable=False)
|
||||||
|
timeframe = Column(String(5), nullable=False) # 1m, 5m, 15m, 1h, 4h, 1d
|
||||||
|
timestamp = Column(DateTime(timezone=True), nullable=False)
|
||||||
|
open = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
high = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
low = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
close = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
volume = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
trades_count = Column(Integer)
|
||||||
|
created_at = Column(DateTime(timezone=True), default=func.now())
|
||||||
|
|
||||||
|
# Constraints
|
||||||
|
__table_args__ = (
|
||||||
|
UniqueConstraint('exchange', 'symbol', 'timeframe', 'timestamp', name='unique_market_data'),
|
||||||
|
Index('idx_market_data_lookup', 'symbol', 'timeframe', 'timestamp'),
|
||||||
|
Index('idx_market_data_recent', 'timestamp'),
|
||||||
|
Index('idx_market_data_symbol', 'symbol'),
|
||||||
|
Index('idx_market_data_timeframe', 'timeframe'),
|
||||||
|
)
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<MarketData({self.symbol} {self.timeframe} {self.timestamp} O:{self.open} C:{self.close})>"
|
||||||
|
|
||||||
|
|
||||||
|
class RawTrade(Base):
|
||||||
|
"""Raw Trade Data - Optional table for detailed backtesting"""
|
||||||
|
__tablename__ = 'raw_trades'
|
||||||
|
|
||||||
|
id = Column(Integer, primary_key=True)
|
||||||
|
exchange = Column(String(50), nullable=False, default='okx')
|
||||||
|
symbol = Column(String(20), nullable=False)
|
||||||
|
timestamp = Column(DateTime(timezone=True), nullable=False)
|
||||||
|
type = Column(String(10), nullable=False) # trade, order, balance, tick, books
|
||||||
|
data = Column(JSON, nullable=False) # Response from exchange
|
||||||
|
created_at = Column(DateTime(timezone=True), default=func.now())
|
||||||
|
|
||||||
|
__table_args__ = (
|
||||||
|
Index('idx_raw_trades_symbol_time', 'symbol', 'timestamp'),
|
||||||
|
Index('idx_raw_trades_type', 'type'),
|
||||||
|
)
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<RawTrade({self.symbol} {self.type} {self.timestamp})>"
|
||||||
|
|
||||||
|
|
||||||
|
class Bot(Base):
|
||||||
|
"""Bot Management - Bot instances with configuration"""
|
||||||
|
__tablename__ = 'bots'
|
||||||
|
|
||||||
|
id = Column(Integer, primary_key=True)
|
||||||
|
name = Column(String(100), nullable=False)
|
||||||
|
strategy_name = Column(String(50), nullable=False)
|
||||||
|
symbol = Column(String(20), nullable=False)
|
||||||
|
timeframe = Column(String(5), nullable=False)
|
||||||
|
status = Column(String(20), nullable=False, default='inactive')
|
||||||
|
config_file = Column(String(200)) # Path to JSON config
|
||||||
|
virtual_balance = Column(DECIMAL(18, 8), default=Decimal('10000'))
|
||||||
|
current_balance = Column(DECIMAL(18, 8), default=Decimal('10000'))
|
||||||
|
last_heartbeat = Column(DateTime(timezone=True))
|
||||||
|
created_at = Column(DateTime(timezone=True), default=func.now())
|
||||||
|
updated_at = Column(DateTime(timezone=True), default=func.now(), onupdate=func.now())
|
||||||
|
|
||||||
|
# Relationships
|
||||||
|
signals = relationship("Signal", back_populates="bot", cascade="all, delete-orphan")
|
||||||
|
trades = relationship("Trade", back_populates="bot", cascade="all, delete-orphan")
|
||||||
|
performance = relationship("BotPerformance", back_populates="bot", cascade="all, delete-orphan")
|
||||||
|
|
||||||
|
__table_args__ = (
|
||||||
|
CheckConstraint("status IN ('active', 'inactive', 'error', 'paused')", name='chk_bot_status'),
|
||||||
|
Index('idx_bots_status', 'status'),
|
||||||
|
Index('idx_bots_symbol', 'symbol'),
|
||||||
|
Index('idx_bots_strategy', 'strategy_name'),
|
||||||
|
Index('idx_bots_last_heartbeat', 'last_heartbeat'),
|
||||||
|
)
|
||||||
|
|
||||||
|
@property
|
||||||
|
def pnl(self) -> Decimal:
|
||||||
|
"""Calculate current profit/loss"""
|
||||||
|
return self.current_balance - self.virtual_balance
|
||||||
|
|
||||||
|
@property
|
||||||
|
def is_active(self) -> bool:
|
||||||
|
"""Check if bot is currently active"""
|
||||||
|
return self.status == 'active'
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<Bot({self.name} - {self.strategy_name} - {self.status})>"
|
||||||
|
|
||||||
|
|
||||||
|
class Signal(Base):
|
||||||
|
"""Trading Signals - Generated by strategies for analysis"""
|
||||||
|
__tablename__ = 'signals'
|
||||||
|
|
||||||
|
id = Column(Integer, primary_key=True)
|
||||||
|
bot_id = Column(Integer, ForeignKey('bots.id', ondelete='CASCADE'), nullable=False)
|
||||||
|
timestamp = Column(DateTime(timezone=True), nullable=False)
|
||||||
|
signal_type = Column(String(10), nullable=False) # buy, sell, hold
|
||||||
|
price = Column(DECIMAL(18, 8))
|
||||||
|
confidence = Column(DECIMAL(5, 4)) # 0.0000 to 1.0000
|
||||||
|
indicators = Column(JSON) # Technical indicator values
|
||||||
|
created_at = Column(DateTime(timezone=True), default=func.now())
|
||||||
|
|
||||||
|
# Relationships
|
||||||
|
bot = relationship("Bot", back_populates="signals")
|
||||||
|
trades = relationship("Trade", back_populates="signal")
|
||||||
|
|
||||||
|
__table_args__ = (
|
||||||
|
CheckConstraint("signal_type IN ('buy', 'sell', 'hold')", name='chk_signal_type'),
|
||||||
|
CheckConstraint("confidence >= 0 AND confidence <= 1", name='chk_confidence'),
|
||||||
|
Index('idx_signals_bot_time', 'bot_id', 'timestamp'),
|
||||||
|
Index('idx_signals_type', 'signal_type'),
|
||||||
|
Index('idx_signals_timestamp', 'timestamp'),
|
||||||
|
)
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<Signal({self.signal_type} - {self.price} - {self.confidence})>"
|
||||||
|
|
||||||
|
|
||||||
|
class Trade(Base):
|
||||||
|
"""Trade Execution Records - Virtual trading results"""
|
||||||
|
__tablename__ = 'trades'
|
||||||
|
|
||||||
|
id = Column(Integer, primary_key=True)
|
||||||
|
bot_id = Column(Integer, ForeignKey('bots.id', ondelete='CASCADE'), nullable=False)
|
||||||
|
signal_id = Column(Integer, ForeignKey('signals.id', ondelete='SET NULL'))
|
||||||
|
timestamp = Column(DateTime(timezone=True), nullable=False)
|
||||||
|
side = Column(String(5), nullable=False) # buy, sell
|
||||||
|
price = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
quantity = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
fees = Column(DECIMAL(18, 8), default=Decimal('0'))
|
||||||
|
pnl = Column(DECIMAL(18, 8)) # Profit/loss for this trade
|
||||||
|
balance_after = Column(DECIMAL(18, 8)) # Portfolio balance after trade
|
||||||
|
created_at = Column(DateTime(timezone=True), default=func.now())
|
||||||
|
|
||||||
|
# Relationships
|
||||||
|
bot = relationship("Bot", back_populates="trades")
|
||||||
|
signal = relationship("Signal", back_populates="trades")
|
||||||
|
|
||||||
|
__table_args__ = (
|
||||||
|
CheckConstraint("side IN ('buy', 'sell')", name='chk_trade_side'),
|
||||||
|
CheckConstraint("price > 0", name='chk_positive_price'),
|
||||||
|
CheckConstraint("quantity > 0", name='chk_positive_quantity'),
|
||||||
|
CheckConstraint("fees >= 0", name='chk_non_negative_fees'),
|
||||||
|
Index('idx_trades_bot_time', 'bot_id', 'timestamp'),
|
||||||
|
Index('idx_trades_side', 'side'),
|
||||||
|
Index('idx_trades_timestamp', 'timestamp'),
|
||||||
|
)
|
||||||
|
|
||||||
|
@property
|
||||||
|
def trade_value(self) -> Decimal:
|
||||||
|
"""Calculate the total value of this trade"""
|
||||||
|
return self.price * self.quantity
|
||||||
|
|
||||||
|
@property
|
||||||
|
def net_pnl(self) -> Decimal:
|
||||||
|
"""Calculate net PnL after fees"""
|
||||||
|
return (self.pnl or Decimal('0')) - self.fees
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<Trade({self.side} {self.quantity} @ {self.price} - PnL: {self.pnl})>"
|
||||||
|
|
||||||
|
|
||||||
|
class BotPerformance(Base):
|
||||||
|
"""Bot Performance Snapshots - For portfolio visualization"""
|
||||||
|
__tablename__ = 'bot_performance'
|
||||||
|
|
||||||
|
id = Column(Integer, primary_key=True)
|
||||||
|
bot_id = Column(Integer, ForeignKey('bots.id', ondelete='CASCADE'), nullable=False)
|
||||||
|
timestamp = Column(DateTime(timezone=True), nullable=False)
|
||||||
|
total_value = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
cash_balance = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
crypto_balance = Column(DECIMAL(18, 8), nullable=False)
|
||||||
|
total_trades = Column(Integer, default=0)
|
||||||
|
winning_trades = Column(Integer, default=0)
|
||||||
|
total_fees = Column(DECIMAL(18, 8), default=Decimal('0'))
|
||||||
|
created_at = Column(DateTime(timezone=True), default=func.now())
|
||||||
|
|
||||||
|
# Relationships
|
||||||
|
bot = relationship("Bot", back_populates="performance")
|
||||||
|
|
||||||
|
__table_args__ = (
|
||||||
|
CheckConstraint(
|
||||||
|
"total_value >= 0 AND cash_balance >= 0 AND crypto_balance >= 0 AND "
|
||||||
|
"total_trades >= 0 AND winning_trades >= 0 AND total_fees >= 0",
|
||||||
|
name='chk_non_negative_values'
|
||||||
|
),
|
||||||
|
CheckConstraint("winning_trades <= total_trades", name='chk_winning_trades_logic'),
|
||||||
|
Index('idx_bot_performance_bot_time', 'bot_id', 'timestamp'),
|
||||||
|
Index('idx_bot_performance_timestamp', 'timestamp'),
|
||||||
|
)
|
||||||
|
|
||||||
|
@property
|
||||||
|
def win_rate(self) -> float:
|
||||||
|
"""Calculate win rate percentage"""
|
||||||
|
if self.total_trades == 0:
|
||||||
|
return 0.0
|
||||||
|
return (self.winning_trades / self.total_trades) * 100
|
||||||
|
|
||||||
|
@property
|
||||||
|
def portfolio_allocation(self) -> Dict[str, float]:
|
||||||
|
"""Calculate portfolio allocation percentages"""
|
||||||
|
if self.total_value == 0:
|
||||||
|
return {"cash": 0.0, "crypto": 0.0}
|
||||||
|
|
||||||
|
cash_pct = float(self.cash_balance / self.total_value * 100)
|
||||||
|
crypto_pct = float(self.crypto_balance / self.total_value * 100)
|
||||||
|
|
||||||
|
return {"cash": cash_pct, "crypto": crypto_pct}
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<BotPerformance(Bot {self.bot_id} - Value: {self.total_value} - Win Rate: {self.win_rate:.2f}%)>"
|
||||||
|
|
||||||
|
|
||||||
|
# Reference tables for system configuration
|
||||||
|
class SupportedTimeframe(Base):
|
||||||
|
"""Supported timeframes configuration"""
|
||||||
|
__tablename__ = 'supported_timeframes'
|
||||||
|
|
||||||
|
timeframe = Column(String(5), primary_key=True)
|
||||||
|
description = Column(String(50))
|
||||||
|
minutes = Column(Integer)
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<SupportedTimeframe({self.timeframe} - {self.description})>"
|
||||||
|
|
||||||
|
|
||||||
|
class SupportedExchange(Base):
|
||||||
|
"""Supported exchanges configuration"""
|
||||||
|
__tablename__ = 'supported_exchanges'
|
||||||
|
|
||||||
|
exchange = Column(String(50), primary_key=True)
|
||||||
|
name = Column(String(100))
|
||||||
|
api_url = Column(String(200))
|
||||||
|
enabled = Column(Boolean, default=True)
|
||||||
|
|
||||||
|
def __repr__(self):
|
||||||
|
return f"<SupportedExchange({self.exchange} - {self.name} - Enabled: {self.enabled})>"
|
||||||
|
|
||||||
|
|
||||||
|
# Helper functions for model operations
|
||||||
|
def get_model_by_table_name(table_name: str):
|
||||||
|
"""Get model class by table name"""
|
||||||
|
table_to_model = {
|
||||||
|
'market_data': MarketData,
|
||||||
|
'raw_trades': RawTrade,
|
||||||
|
'bots': Bot,
|
||||||
|
'signals': Signal,
|
||||||
|
'trades': Trade,
|
||||||
|
'bot_performance': BotPerformance,
|
||||||
|
'supported_timeframes': SupportedTimeframe,
|
||||||
|
'supported_exchanges': SupportedExchange,
|
||||||
|
}
|
||||||
|
return table_to_model.get(table_name)
|
||||||
|
|
||||||
|
|
||||||
|
def create_all_tables(engine):
|
||||||
|
"""Create all tables in the database"""
|
||||||
|
Base.metadata.create_all(engine)
|
||||||
|
|
||||||
|
|
||||||
|
def drop_all_tables(engine):
|
||||||
|
"""Drop all tables from the database"""
|
||||||
|
Base.metadata.drop_all(engine)
|
||||||
329
database/schema.sql
Normal file
329
database/schema.sql
Normal file
@ -0,0 +1,329 @@
|
|||||||
|
-- Database Schema for Crypto Trading Bot Platform
|
||||||
|
-- Following PRD specifications with optimized schema for time-series data
|
||||||
|
-- Version: 1.0
|
||||||
|
-- Author: Generated following PRD requirements
|
||||||
|
|
||||||
|
-- Create extensions
|
||||||
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||||
|
CREATE EXTENSION IF NOT EXISTS "timescaledb" CASCADE;
|
||||||
|
|
||||||
|
-- Set timezone to UTC for consistency
|
||||||
|
SET timezone = 'UTC';
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- MARKET DATA TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- OHLCV Market Data (primary table for bot operations)
|
||||||
|
-- This is the main table that bots will use for trading decisions
|
||||||
|
CREATE TABLE market_data (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
exchange VARCHAR(50) NOT NULL DEFAULT 'okx',
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timeframe VARCHAR(5) NOT NULL, -- 1m, 5m, 15m, 1h, 4h, 1d
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
open DECIMAL(18,8) NOT NULL,
|
||||||
|
high DECIMAL(18,8) NOT NULL,
|
||||||
|
low DECIMAL(18,8) NOT NULL,
|
||||||
|
close DECIMAL(18,8) NOT NULL,
|
||||||
|
volume DECIMAL(18,8) NOT NULL,
|
||||||
|
trades_count INTEGER, -- number of trades in this candle
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT unique_market_data UNIQUE(exchange, symbol, timeframe, timestamp)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('market_data', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Create optimized indexes for market data
|
||||||
|
CREATE INDEX idx_market_data_lookup ON market_data(symbol, timeframe, timestamp);
|
||||||
|
CREATE INDEX idx_market_data_recent ON market_data(timestamp DESC) WHERE timestamp > NOW() - INTERVAL '7 days';
|
||||||
|
CREATE INDEX idx_market_data_symbol ON market_data(symbol);
|
||||||
|
CREATE INDEX idx_market_data_timeframe ON market_data(timeframe);
|
||||||
|
|
||||||
|
-- Raw Trade Data (optional, for detailed backtesting only)
|
||||||
|
-- This table is partitioned by timestamp for better performance
|
||||||
|
CREATE TABLE raw_trades (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
exchange VARCHAR(50) NOT NULL DEFAULT 'okx',
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
type VARCHAR(10) NOT NULL, -- trade, order, balance, tick, books
|
||||||
|
data JSONB NOT NULL, -- response from the exchange
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW()
|
||||||
|
) PARTITION BY RANGE (timestamp);
|
||||||
|
|
||||||
|
-- Create initial partition for current month
|
||||||
|
CREATE TABLE raw_trades_current PARTITION OF raw_trades
|
||||||
|
FOR VALUES FROM (date_trunc('month', NOW())) TO (date_trunc('month', NOW()) + INTERVAL '1 month');
|
||||||
|
|
||||||
|
-- Index for raw trades
|
||||||
|
CREATE INDEX idx_raw_trades_symbol_time ON raw_trades(symbol, timestamp);
|
||||||
|
CREATE INDEX idx_raw_trades_type ON raw_trades(type);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- BOT MANAGEMENT TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Bot Management (simplified)
|
||||||
|
CREATE TABLE bots (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
name VARCHAR(100) NOT NULL,
|
||||||
|
strategy_name VARCHAR(50) NOT NULL,
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timeframe VARCHAR(5) NOT NULL,
|
||||||
|
status VARCHAR(20) NOT NULL DEFAULT 'inactive', -- active, inactive, error, paused
|
||||||
|
config_file VARCHAR(200), -- path to JSON config
|
||||||
|
virtual_balance DECIMAL(18,8) DEFAULT 10000,
|
||||||
|
current_balance DECIMAL(18,8) DEFAULT 10000,
|
||||||
|
last_heartbeat TIMESTAMPTZ,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_bot_status CHECK (status IN ('active', 'inactive', 'error', 'paused'))
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Indexes for bot management
|
||||||
|
CREATE INDEX idx_bots_status ON bots(status);
|
||||||
|
CREATE INDEX idx_bots_symbol ON bots(symbol);
|
||||||
|
CREATE INDEX idx_bots_strategy ON bots(strategy_name);
|
||||||
|
CREATE INDEX idx_bots_last_heartbeat ON bots(last_heartbeat);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- TRADING SIGNAL TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Trading Signals (for analysis and debugging)
|
||||||
|
CREATE TABLE signals (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
signal_type VARCHAR(10) NOT NULL, -- buy, sell, hold
|
||||||
|
price DECIMAL(18,8),
|
||||||
|
confidence DECIMAL(5,4), -- signal confidence score (0.0000 to 1.0000)
|
||||||
|
indicators JSONB, -- technical indicator values
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_signal_type CHECK (signal_type IN ('buy', 'sell', 'hold')),
|
||||||
|
CONSTRAINT chk_confidence CHECK (confidence >= 0 AND confidence <= 1)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert signals to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('signals', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Indexes for signals
|
||||||
|
CREATE INDEX idx_signals_bot_time ON signals(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_signals_type ON signals(signal_type);
|
||||||
|
CREATE INDEX idx_signals_timestamp ON signals(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- TRADE EXECUTION TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Trade Execution Records
|
||||||
|
CREATE TABLE trades (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
signal_id INTEGER REFERENCES signals(id) ON DELETE SET NULL,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
side VARCHAR(5) NOT NULL, -- buy, sell
|
||||||
|
price DECIMAL(18,8) NOT NULL,
|
||||||
|
quantity DECIMAL(18,8) NOT NULL,
|
||||||
|
fees DECIMAL(18,8) DEFAULT 0,
|
||||||
|
pnl DECIMAL(18,8), -- profit/loss for this trade
|
||||||
|
balance_after DECIMAL(18,8), -- portfolio balance after trade
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_trade_side CHECK (side IN ('buy', 'sell')),
|
||||||
|
CONSTRAINT chk_positive_price CHECK (price > 0),
|
||||||
|
CONSTRAINT chk_positive_quantity CHECK (quantity > 0),
|
||||||
|
CONSTRAINT chk_non_negative_fees CHECK (fees >= 0)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert trades to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('trades', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Indexes for trades
|
||||||
|
CREATE INDEX idx_trades_bot_time ON trades(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_trades_side ON trades(side);
|
||||||
|
CREATE INDEX idx_trades_timestamp ON trades(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- PERFORMANCE TRACKING TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Performance Snapshots (for plotting portfolio over time)
|
||||||
|
CREATE TABLE bot_performance (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
total_value DECIMAL(18,8) NOT NULL, -- current portfolio value
|
||||||
|
cash_balance DECIMAL(18,8) NOT NULL,
|
||||||
|
crypto_balance DECIMAL(18,8) NOT NULL,
|
||||||
|
total_trades INTEGER DEFAULT 0,
|
||||||
|
winning_trades INTEGER DEFAULT 0,
|
||||||
|
total_fees DECIMAL(18,8) DEFAULT 0,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_non_negative_values CHECK (
|
||||||
|
total_value >= 0 AND
|
||||||
|
cash_balance >= 0 AND
|
||||||
|
crypto_balance >= 0 AND
|
||||||
|
total_trades >= 0 AND
|
||||||
|
winning_trades >= 0 AND
|
||||||
|
total_fees >= 0
|
||||||
|
),
|
||||||
|
CONSTRAINT chk_winning_trades_logic CHECK (winning_trades <= total_trades)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Convert bot_performance to hypertable for TimescaleDB optimization
|
||||||
|
SELECT create_hypertable('bot_performance', 'timestamp', if_not_exists => TRUE);
|
||||||
|
|
||||||
|
-- Indexes for bot performance
|
||||||
|
CREATE INDEX idx_bot_performance_bot_time ON bot_performance(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_bot_performance_timestamp ON bot_performance(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- FUNCTIONS AND TRIGGERS
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Function to update bot updated_at timestamp
|
||||||
|
CREATE OR REPLACE FUNCTION update_bot_timestamp()
|
||||||
|
RETURNS TRIGGER AS $$
|
||||||
|
BEGIN
|
||||||
|
NEW.updated_at = NOW();
|
||||||
|
RETURN NEW;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- Trigger to automatically update bot updated_at
|
||||||
|
CREATE TRIGGER trigger_update_bot_timestamp
|
||||||
|
BEFORE UPDATE ON bots
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE FUNCTION update_bot_timestamp();
|
||||||
|
|
||||||
|
-- Function to create monthly partition for raw_trades
|
||||||
|
CREATE OR REPLACE FUNCTION create_monthly_partition_for_raw_trades(partition_date DATE)
|
||||||
|
RETURNS VOID AS $$
|
||||||
|
DECLARE
|
||||||
|
partition_name TEXT;
|
||||||
|
start_date DATE;
|
||||||
|
end_date DATE;
|
||||||
|
BEGIN
|
||||||
|
start_date := date_trunc('month', partition_date);
|
||||||
|
end_date := start_date + INTERVAL '1 month';
|
||||||
|
partition_name := 'raw_trades_' || to_char(start_date, 'YYYY_MM');
|
||||||
|
|
||||||
|
EXECUTE format('CREATE TABLE IF NOT EXISTS %I PARTITION OF raw_trades
|
||||||
|
FOR VALUES FROM (%L) TO (%L)',
|
||||||
|
partition_name, start_date, end_date);
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- VIEWS FOR COMMON QUERIES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- View for bot status overview
|
||||||
|
CREATE VIEW bot_status_overview AS
|
||||||
|
SELECT
|
||||||
|
b.id,
|
||||||
|
b.name,
|
||||||
|
b.strategy_name,
|
||||||
|
b.symbol,
|
||||||
|
b.status,
|
||||||
|
b.current_balance,
|
||||||
|
b.virtual_balance,
|
||||||
|
(b.current_balance - b.virtual_balance) as pnl,
|
||||||
|
b.last_heartbeat,
|
||||||
|
COUNT(t.id) as total_trades,
|
||||||
|
COALESCE(SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END), 0) as winning_trades
|
||||||
|
FROM bots b
|
||||||
|
LEFT JOIN trades t ON b.id = t.bot_id
|
||||||
|
GROUP BY b.id, b.name, b.strategy_name, b.symbol, b.status,
|
||||||
|
b.current_balance, b.virtual_balance, b.last_heartbeat;
|
||||||
|
|
||||||
|
-- View for recent market data
|
||||||
|
CREATE VIEW recent_market_data AS
|
||||||
|
SELECT
|
||||||
|
symbol,
|
||||||
|
timeframe,
|
||||||
|
timestamp,
|
||||||
|
open,
|
||||||
|
high,
|
||||||
|
low,
|
||||||
|
close,
|
||||||
|
volume,
|
||||||
|
trades_count
|
||||||
|
FROM market_data
|
||||||
|
WHERE timestamp > NOW() - INTERVAL '24 hours'
|
||||||
|
ORDER BY symbol, timeframe, timestamp DESC;
|
||||||
|
|
||||||
|
-- View for trading performance summary
|
||||||
|
CREATE VIEW trading_performance_summary AS
|
||||||
|
SELECT
|
||||||
|
t.bot_id,
|
||||||
|
b.name as bot_name,
|
||||||
|
COUNT(t.id) as total_trades,
|
||||||
|
SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END) as winning_trades,
|
||||||
|
ROUND((SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END)::DECIMAL / COUNT(t.id)) * 100, 2) as win_rate_percent,
|
||||||
|
ROUND(SUM(t.pnl), 4) as total_pnl,
|
||||||
|
ROUND(SUM(t.fees), 4) as total_fees,
|
||||||
|
MIN(t.timestamp) as first_trade,
|
||||||
|
MAX(t.timestamp) as last_trade
|
||||||
|
FROM trades t
|
||||||
|
JOIN bots b ON t.bot_id = b.id
|
||||||
|
GROUP BY t.bot_id, b.name
|
||||||
|
ORDER BY total_pnl DESC;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- INITIAL DATA SEEDING
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Insert sample timeframes that the system supports
|
||||||
|
CREATE TABLE IF NOT EXISTS supported_timeframes (
|
||||||
|
timeframe VARCHAR(5) PRIMARY KEY,
|
||||||
|
description VARCHAR(50),
|
||||||
|
minutes INTEGER
|
||||||
|
);
|
||||||
|
|
||||||
|
INSERT INTO supported_timeframes (timeframe, description, minutes) VALUES
|
||||||
|
('1m', '1 Minute', 1),
|
||||||
|
('5m', '5 Minutes', 5),
|
||||||
|
('15m', '15 Minutes', 15),
|
||||||
|
('1h', '1 Hour', 60),
|
||||||
|
('4h', '4 Hours', 240),
|
||||||
|
('1d', '1 Day', 1440)
|
||||||
|
ON CONFLICT (timeframe) DO NOTHING;
|
||||||
|
|
||||||
|
-- Insert sample exchanges
|
||||||
|
CREATE TABLE IF NOT EXISTS supported_exchanges (
|
||||||
|
exchange VARCHAR(50) PRIMARY KEY,
|
||||||
|
name VARCHAR(100),
|
||||||
|
api_url VARCHAR(200),
|
||||||
|
enabled BOOLEAN DEFAULT true
|
||||||
|
);
|
||||||
|
|
||||||
|
INSERT INTO supported_exchanges (exchange, name, api_url, enabled) VALUES
|
||||||
|
('okx', 'OKX Exchange', 'https://www.okx.com/api/v5', true),
|
||||||
|
('binance', 'Binance Exchange', 'https://api.binance.com/api/v3', false),
|
||||||
|
('coinbase', 'Coinbase Pro', 'https://api.exchange.coinbase.com', false)
|
||||||
|
ON CONFLICT (exchange) DO NOTHING;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- COMMENTS FOR DOCUMENTATION
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
COMMENT ON TABLE market_data IS 'Primary OHLCV market data table optimized for bot operations and backtesting';
|
||||||
|
COMMENT ON TABLE raw_trades IS 'Optional raw trade data for detailed backtesting (partitioned by month)';
|
||||||
|
COMMENT ON TABLE bots IS 'Bot instance management with JSON configuration references';
|
||||||
|
COMMENT ON TABLE signals IS 'Trading signals generated by strategies with confidence scores';
|
||||||
|
COMMENT ON TABLE trades IS 'Virtual trade execution records with P&L tracking';
|
||||||
|
COMMENT ON TABLE bot_performance IS 'Portfolio performance snapshots for visualization';
|
||||||
|
|
||||||
|
COMMENT ON COLUMN market_data.timestamp IS 'Right-aligned timestamp (candle close time) following exchange standards';
|
||||||
|
COMMENT ON COLUMN bots.config_file IS 'Path to JSON configuration file for strategy parameters';
|
||||||
|
COMMENT ON COLUMN signals.confidence IS 'Signal confidence score from 0.0000 to 1.0000';
|
||||||
|
COMMENT ON COLUMN trades.pnl IS 'Profit/Loss for this specific trade in base currency';
|
||||||
|
COMMENT ON COLUMN bot_performance.total_value IS 'Current total portfolio value (cash + crypto)';
|
||||||
|
|
||||||
|
-- Grant permissions to dashboard user
|
||||||
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO dashboard;
|
||||||
|
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO dashboard;
|
||||||
|
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO dashboard;
|
||||||
276
database/schema_clean.sql
Normal file
276
database/schema_clean.sql
Normal file
@ -0,0 +1,276 @@
|
|||||||
|
-- Database Schema for Crypto Trading Bot Platform (Clean Version)
|
||||||
|
-- Following PRD specifications - optimized for rapid development
|
||||||
|
-- Version: 1.0 (without hypertables for now)
|
||||||
|
-- Author: Generated following PRD requirements
|
||||||
|
|
||||||
|
-- Create extensions
|
||||||
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||||
|
|
||||||
|
-- Set timezone to UTC for consistency
|
||||||
|
SET timezone = 'UTC';
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- MARKET DATA TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- OHLCV Market Data (primary table for bot operations)
|
||||||
|
CREATE TABLE market_data (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
exchange VARCHAR(50) NOT NULL DEFAULT 'okx',
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timeframe VARCHAR(5) NOT NULL, -- 1m, 5m, 15m, 1h, 4h, 1d
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
open DECIMAL(18,8) NOT NULL,
|
||||||
|
high DECIMAL(18,8) NOT NULL,
|
||||||
|
low DECIMAL(18,8) NOT NULL,
|
||||||
|
close DECIMAL(18,8) NOT NULL,
|
||||||
|
volume DECIMAL(18,8) NOT NULL,
|
||||||
|
trades_count INTEGER, -- number of trades in this candle
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT unique_market_data UNIQUE(exchange, symbol, timeframe, timestamp)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Create optimized indexes for market data
|
||||||
|
CREATE INDEX idx_market_data_lookup ON market_data(symbol, timeframe, timestamp);
|
||||||
|
CREATE INDEX idx_market_data_symbol ON market_data(symbol);
|
||||||
|
CREATE INDEX idx_market_data_timeframe ON market_data(timeframe);
|
||||||
|
CREATE INDEX idx_market_data_recent ON market_data(timestamp DESC);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- BOT MANAGEMENT TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Bot Management (simplified)
|
||||||
|
CREATE TABLE bots (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
name VARCHAR(100) NOT NULL,
|
||||||
|
strategy_name VARCHAR(50) NOT NULL,
|
||||||
|
symbol VARCHAR(20) NOT NULL,
|
||||||
|
timeframe VARCHAR(5) NOT NULL,
|
||||||
|
status VARCHAR(20) NOT NULL DEFAULT 'inactive', -- active, inactive, error, paused
|
||||||
|
config_file VARCHAR(200), -- path to JSON config
|
||||||
|
virtual_balance DECIMAL(18,8) DEFAULT 10000,
|
||||||
|
current_balance DECIMAL(18,8) DEFAULT 10000,
|
||||||
|
last_heartbeat TIMESTAMPTZ,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_bot_status CHECK (status IN ('active', 'inactive', 'error', 'paused'))
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Indexes for bot management
|
||||||
|
CREATE INDEX idx_bots_status ON bots(status);
|
||||||
|
CREATE INDEX idx_bots_symbol ON bots(symbol);
|
||||||
|
CREATE INDEX idx_bots_strategy ON bots(strategy_name);
|
||||||
|
CREATE INDEX idx_bots_last_heartbeat ON bots(last_heartbeat);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- TRADING SIGNAL TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Trading Signals (for analysis and debugging)
|
||||||
|
CREATE TABLE signals (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
signal_type VARCHAR(10) NOT NULL, -- buy, sell, hold
|
||||||
|
price DECIMAL(18,8),
|
||||||
|
confidence DECIMAL(5,4), -- signal confidence score (0.0000 to 1.0000)
|
||||||
|
indicators JSONB, -- technical indicator values
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_signal_type CHECK (signal_type IN ('buy', 'sell', 'hold')),
|
||||||
|
CONSTRAINT chk_confidence CHECK (confidence >= 0 AND confidence <= 1)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Indexes for signals
|
||||||
|
CREATE INDEX idx_signals_bot_time ON signals(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_signals_type ON signals(signal_type);
|
||||||
|
CREATE INDEX idx_signals_timestamp ON signals(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- TRADE EXECUTION TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Trade Execution Records
|
||||||
|
CREATE TABLE trades (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
signal_id INTEGER REFERENCES signals(id) ON DELETE SET NULL,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
side VARCHAR(5) NOT NULL, -- buy, sell
|
||||||
|
price DECIMAL(18,8) NOT NULL,
|
||||||
|
quantity DECIMAL(18,8) NOT NULL,
|
||||||
|
fees DECIMAL(18,8) DEFAULT 0,
|
||||||
|
pnl DECIMAL(18,8), -- profit/loss for this trade
|
||||||
|
balance_after DECIMAL(18,8), -- portfolio balance after trade
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_trade_side CHECK (side IN ('buy', 'sell')),
|
||||||
|
CONSTRAINT chk_positive_price CHECK (price > 0),
|
||||||
|
CONSTRAINT chk_positive_quantity CHECK (quantity > 0),
|
||||||
|
CONSTRAINT chk_non_negative_fees CHECK (fees >= 0)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Indexes for trades
|
||||||
|
CREATE INDEX idx_trades_bot_time ON trades(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_trades_side ON trades(side);
|
||||||
|
CREATE INDEX idx_trades_timestamp ON trades(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- PERFORMANCE TRACKING TABLES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Performance Snapshots (for plotting portfolio over time)
|
||||||
|
CREATE TABLE bot_performance (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
bot_id INTEGER REFERENCES bots(id) ON DELETE CASCADE,
|
||||||
|
timestamp TIMESTAMPTZ NOT NULL,
|
||||||
|
total_value DECIMAL(18,8) NOT NULL, -- current portfolio value
|
||||||
|
cash_balance DECIMAL(18,8) NOT NULL,
|
||||||
|
crypto_balance DECIMAL(18,8) NOT NULL,
|
||||||
|
total_trades INTEGER DEFAULT 0,
|
||||||
|
winning_trades INTEGER DEFAULT 0,
|
||||||
|
total_fees DECIMAL(18,8) DEFAULT 0,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
CONSTRAINT chk_non_negative_values CHECK (
|
||||||
|
total_value >= 0 AND
|
||||||
|
cash_balance >= 0 AND
|
||||||
|
crypto_balance >= 0 AND
|
||||||
|
total_trades >= 0 AND
|
||||||
|
winning_trades >= 0 AND
|
||||||
|
total_fees >= 0
|
||||||
|
),
|
||||||
|
CONSTRAINT chk_winning_trades_logic CHECK (winning_trades <= total_trades)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Indexes for bot performance
|
||||||
|
CREATE INDEX idx_bot_performance_bot_time ON bot_performance(bot_id, timestamp);
|
||||||
|
CREATE INDEX idx_bot_performance_timestamp ON bot_performance(timestamp);
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- FUNCTIONS AND TRIGGERS
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Function to update bot updated_at timestamp
|
||||||
|
CREATE OR REPLACE FUNCTION update_bot_timestamp()
|
||||||
|
RETURNS TRIGGER AS $$
|
||||||
|
BEGIN
|
||||||
|
NEW.updated_at = NOW();
|
||||||
|
RETURN NEW;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- Trigger to automatically update bot updated_at
|
||||||
|
CREATE TRIGGER trigger_update_bot_timestamp
|
||||||
|
BEFORE UPDATE ON bots
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE FUNCTION update_bot_timestamp();
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- VIEWS FOR COMMON QUERIES
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- View for bot status overview
|
||||||
|
CREATE VIEW bot_status_overview AS
|
||||||
|
SELECT
|
||||||
|
b.id,
|
||||||
|
b.name,
|
||||||
|
b.strategy_name,
|
||||||
|
b.symbol,
|
||||||
|
b.status,
|
||||||
|
b.current_balance,
|
||||||
|
b.virtual_balance,
|
||||||
|
(b.current_balance - b.virtual_balance) as pnl,
|
||||||
|
b.last_heartbeat,
|
||||||
|
COUNT(t.id) as total_trades,
|
||||||
|
COALESCE(SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END), 0) as winning_trades
|
||||||
|
FROM bots b
|
||||||
|
LEFT JOIN trades t ON b.id = t.bot_id
|
||||||
|
GROUP BY b.id, b.name, b.strategy_name, b.symbol, b.status,
|
||||||
|
b.current_balance, b.virtual_balance, b.last_heartbeat;
|
||||||
|
|
||||||
|
-- View for recent market data
|
||||||
|
CREATE VIEW recent_market_data AS
|
||||||
|
SELECT
|
||||||
|
symbol,
|
||||||
|
timeframe,
|
||||||
|
timestamp,
|
||||||
|
open,
|
||||||
|
high,
|
||||||
|
low,
|
||||||
|
close,
|
||||||
|
volume,
|
||||||
|
trades_count
|
||||||
|
FROM market_data
|
||||||
|
WHERE timestamp > NOW() - INTERVAL '24 hours'
|
||||||
|
ORDER BY symbol, timeframe, timestamp DESC;
|
||||||
|
|
||||||
|
-- View for trading performance summary
|
||||||
|
CREATE VIEW trading_performance_summary AS
|
||||||
|
SELECT
|
||||||
|
t.bot_id,
|
||||||
|
b.name as bot_name,
|
||||||
|
COUNT(t.id) as total_trades,
|
||||||
|
SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END) as winning_trades,
|
||||||
|
ROUND((SUM(CASE WHEN t.pnl > 0 THEN 1 ELSE 0 END)::DECIMAL / COUNT(t.id)) * 100, 2) as win_rate_percent,
|
||||||
|
ROUND(SUM(t.pnl), 4) as total_pnl,
|
||||||
|
ROUND(SUM(t.fees), 4) as total_fees,
|
||||||
|
MIN(t.timestamp) as first_trade,
|
||||||
|
MAX(t.timestamp) as last_trade
|
||||||
|
FROM trades t
|
||||||
|
JOIN bots b ON t.bot_id = b.id
|
||||||
|
GROUP BY t.bot_id, b.name
|
||||||
|
ORDER BY total_pnl DESC;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- INITIAL DATA SEEDING
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Insert sample timeframes that the system supports
|
||||||
|
CREATE TABLE IF NOT EXISTS supported_timeframes (
|
||||||
|
timeframe VARCHAR(5) PRIMARY KEY,
|
||||||
|
description VARCHAR(50),
|
||||||
|
minutes INTEGER
|
||||||
|
);
|
||||||
|
|
||||||
|
INSERT INTO supported_timeframes (timeframe, description, minutes) VALUES
|
||||||
|
('1m', '1 Minute', 1),
|
||||||
|
('5m', '5 Minutes', 5),
|
||||||
|
('15m', '15 Minutes', 15),
|
||||||
|
('1h', '1 Hour', 60),
|
||||||
|
('4h', '4 Hours', 240),
|
||||||
|
('1d', '1 Day', 1440)
|
||||||
|
ON CONFLICT (timeframe) DO NOTHING;
|
||||||
|
|
||||||
|
-- Insert sample exchanges
|
||||||
|
CREATE TABLE IF NOT EXISTS supported_exchanges (
|
||||||
|
exchange VARCHAR(50) PRIMARY KEY,
|
||||||
|
name VARCHAR(100),
|
||||||
|
api_url VARCHAR(200),
|
||||||
|
enabled BOOLEAN DEFAULT true
|
||||||
|
);
|
||||||
|
|
||||||
|
INSERT INTO supported_exchanges (exchange, name, api_url, enabled) VALUES
|
||||||
|
('okx', 'OKX Exchange', 'https://www.okx.com/api/v5', true),
|
||||||
|
('binance', 'Binance Exchange', 'https://api.binance.com/api/v3', false),
|
||||||
|
('coinbase', 'Coinbase Pro', 'https://api.exchange.coinbase.com', false)
|
||||||
|
ON CONFLICT (exchange) DO NOTHING;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- COMMENTS FOR DOCUMENTATION
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
COMMENT ON TABLE market_data IS 'Primary OHLCV market data table optimized for bot operations and backtesting';
|
||||||
|
COMMENT ON TABLE bots IS 'Bot instance management with JSON configuration references';
|
||||||
|
COMMENT ON TABLE signals IS 'Trading signals generated by strategies with confidence scores';
|
||||||
|
COMMENT ON TABLE trades IS 'Virtual trade execution records with P&L tracking';
|
||||||
|
COMMENT ON TABLE bot_performance IS 'Portfolio performance snapshots for visualization';
|
||||||
|
|
||||||
|
COMMENT ON COLUMN market_data.timestamp IS 'Right-aligned timestamp (candle close time) following exchange standards';
|
||||||
|
COMMENT ON COLUMN bots.config_file IS 'Path to JSON configuration file for strategy parameters';
|
||||||
|
COMMENT ON COLUMN signals.confidence IS 'Signal confidence score from 0.0000 to 1.0000';
|
||||||
|
COMMENT ON COLUMN trades.pnl IS 'Profit/Loss for this specific trade in base currency';
|
||||||
|
COMMENT ON COLUMN bot_performance.total_value IS 'Current total portfolio value (cash + crypto)';
|
||||||
|
|
||||||
|
-- Grant permissions to dashboard user
|
||||||
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO dashboard;
|
||||||
|
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO dashboard;
|
||||||
|
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO dashboard;
|
||||||
@ -1,7 +1,8 @@
|
|||||||
services:
|
services:
|
||||||
postgres:
|
postgres:
|
||||||
image: postgres:15-alpine
|
image: timescale/timescaledb:latest-pg15
|
||||||
container_name: dashboard_postgres
|
container_name: dashboard_postgres
|
||||||
|
command: ["postgres", "-c", "shared_preload_libraries=timescaledb"]
|
||||||
environment:
|
environment:
|
||||||
POSTGRES_DB: ${POSTGRES_DB:-dashboard}
|
POSTGRES_DB: ${POSTGRES_DB:-dashboard}
|
||||||
POSTGRES_USER: ${POSTGRES_USER:-dashboard}
|
POSTGRES_USER: ${POSTGRES_USER:-dashboard}
|
||||||
|
|||||||
@ -70,17 +70,18 @@ REDIS_PASSWORD=redis987secure
|
|||||||
|
|
||||||
### 1. Start Database Services
|
### 1. Start Database Services
|
||||||
|
|
||||||
Start PostgreSQL and Redis using Docker Compose:
|
Start PostgreSQL with TimescaleDB and Redis using Docker Compose:
|
||||||
|
|
||||||
```powershell
|
```powershell
|
||||||
docker-compose up -d
|
docker-compose up -d
|
||||||
```
|
```
|
||||||
|
|
||||||
This will:
|
This will:
|
||||||
- Create a PostgreSQL database on port `5434`
|
- Create a PostgreSQL database with TimescaleDB extension on port `5434`
|
||||||
- Create a Redis instance on port `6379`
|
- Create a Redis instance on port `6379`
|
||||||
- Set up persistent volumes for data storage
|
- Set up persistent volumes for data storage
|
||||||
- Configure password authentication
|
- Configure password authentication
|
||||||
|
- **Automatically initialize the database schema** using scripts in `database/init/`
|
||||||
|
|
||||||
### 2. Verify Services are Running
|
### 2. Verify Services are Running
|
||||||
|
|
||||||
@ -91,20 +92,41 @@ docker-compose ps
|
|||||||
|
|
||||||
Expected output:
|
Expected output:
|
||||||
```
|
```
|
||||||
NAME IMAGE COMMAND SERVICE CREATED STATUS PORTS
|
NAME IMAGE COMMAND SERVICE CREATED STATUS PORTS
|
||||||
dashboard_postgres postgres:15-alpine "docker-entrypoint.s…" postgres X minutes ago Up X minutes (healthy) 0.0.0.0:5434->5432/tcp
|
dashboard_postgres timescale/timescaledb:latest-pg15 "docker-entrypoint.s…" postgres X minutes ago Up X minutes (healthy) 0.0.0.0:5434->5432/tcp
|
||||||
dashboard_redis redis:7-alpine "docker-entrypoint.s…" redis X minutes ago Up X minutes (healthy) 0.0.0.0:6379->6379/tcp
|
dashboard_redis redis:7-alpine "docker-entrypoint.s…" redis X minutes ago Up X minutes (healthy) 0.0.0.0:6379->6379/tcp
|
||||||
```
|
```
|
||||||
|
|
||||||
### 3. Test Database Connections
|
### 3. Verify Database Schema
|
||||||
|
|
||||||
|
Check if tables were created successfully:
|
||||||
|
```powershell
|
||||||
|
docker exec dashboard_postgres psql -U dashboard -d dashboard -c "\dt"
|
||||||
|
```
|
||||||
|
|
||||||
|
Expected output should show tables: `bots`, `bot_performance`, `market_data`, `signals`, `supported_exchanges`, `supported_timeframes`, `trades`
|
||||||
|
|
||||||
|
### 4. Manual Schema Application (If Needed)
|
||||||
|
|
||||||
|
If the automatic initialization didn't work, you can manually apply the schema:
|
||||||
|
|
||||||
|
```powershell
|
||||||
|
# Apply the complete schema
|
||||||
|
Get-Content database/schema.sql | docker exec -i dashboard_postgres psql -U dashboard -d dashboard
|
||||||
|
|
||||||
|
# Or apply the clean version (without TimescaleDB hypertables)
|
||||||
|
Get-Content database/schema_clean.sql | docker exec -i dashboard_postgres psql -U dashboard -d dashboard
|
||||||
|
```
|
||||||
|
|
||||||
|
### 5. Test Database Connections
|
||||||
|
|
||||||
Test PostgreSQL connection:
|
Test PostgreSQL connection:
|
||||||
```powershell
|
```powershell
|
||||||
# Test port accessibility
|
# Test port accessibility
|
||||||
Test-NetConnection -ComputerName localhost -Port 5434
|
Test-NetConnection -ComputerName localhost -Port 5434
|
||||||
|
|
||||||
# Test database connection (from inside container)
|
# Test database connection and check schema
|
||||||
docker exec dashboard_postgres psql -h localhost -p 5432 -U dashboard -d dashboard -c "SELECT version();"
|
docker exec dashboard_postgres psql -U dashboard -d dashboard -c "SELECT COUNT(*) FROM bots;"
|
||||||
```
|
```
|
||||||
|
|
||||||
Test Redis connection:
|
Test Redis connection:
|
||||||
@ -140,11 +162,16 @@ uv run <command>
|
|||||||
source .venv/bin/activate
|
source .venv/bin/activate
|
||||||
```
|
```
|
||||||
|
|
||||||
### 3. Initialize Database Schema
|
### 3. Verify Database Schema (Optional)
|
||||||
|
|
||||||
|
The database schema is automatically initialized when Docker containers start. You can verify it's working:
|
||||||
|
|
||||||
```powershell
|
```powershell
|
||||||
# Run database migrations (when implemented)
|
# Check if all tables exist
|
||||||
uv run python scripts/init_db.py
|
docker exec dashboard_postgres psql -U dashboard -d dashboard -c "SELECT table_name FROM information_schema.tables WHERE table_schema = 'public' ORDER BY table_name;"
|
||||||
|
|
||||||
|
# Verify sample data was inserted
|
||||||
|
docker exec dashboard_postgres psql -U dashboard -d dashboard -c "SELECT * FROM supported_timeframes;"
|
||||||
```
|
```
|
||||||
|
|
||||||
## Running the Application
|
## Running the Application
|
||||||
@ -320,7 +347,33 @@ uv run python test_connection.py
|
|||||||
- Reset database: `docker-compose down -v && docker-compose up -d`
|
- Reset database: `docker-compose down -v && docker-compose up -d`
|
||||||
- Wait for database initialization (30-60 seconds)
|
- Wait for database initialization (30-60 seconds)
|
||||||
|
|
||||||
#### 4. Python Dependencies Issues
|
#### 4. Database Schema Not Created
|
||||||
|
|
||||||
|
**Error**: Tables don't exist or `\dt` shows no tables
|
||||||
|
|
||||||
|
**Solution**:
|
||||||
|
```powershell
|
||||||
|
# Check initialization logs
|
||||||
|
docker-compose logs postgres
|
||||||
|
|
||||||
|
# Manually apply schema if needed
|
||||||
|
Get-Content database/schema_clean.sql | docker exec -i dashboard_postgres psql -U dashboard -d dashboard
|
||||||
|
|
||||||
|
# Verify tables were created
|
||||||
|
docker exec dashboard_postgres psql -U dashboard -d dashboard -c "\dt"
|
||||||
|
```
|
||||||
|
|
||||||
|
#### 5. TimescaleDB Extension Issues
|
||||||
|
|
||||||
|
**Error**: `extension "timescaledb" is not available`
|
||||||
|
|
||||||
|
**Solution**:
|
||||||
|
- Ensure using TimescaleDB image: `timescale/timescaledb:latest-pg15`
|
||||||
|
- Check docker-compose.yml has correct image
|
||||||
|
- Restart containers: `docker-compose down && docker-compose up -d`
|
||||||
|
- Use clean schema if needed: `database/schema_clean.sql`
|
||||||
|
|
||||||
|
#### 6. Python Dependencies Issues
|
||||||
|
|
||||||
**Error**: Package installation failures
|
**Error**: Package installation failures
|
||||||
|
|
||||||
|
|||||||
@ -3,6 +3,7 @@
|
|||||||
- `app.py` - Main Dash application entry point and dashboard interface
|
- `app.py` - Main Dash application entry point and dashboard interface
|
||||||
- `bot_manager.py` - Bot lifecycle management and coordination
|
- `bot_manager.py` - Bot lifecycle management and coordination
|
||||||
- `database/models.py` - PostgreSQL database models and schema definitions
|
- `database/models.py` - PostgreSQL database models and schema definitions
|
||||||
|
- `database/schema.sql` - Complete database schema with all tables, indexes, and constraints
|
||||||
- `database/connection.py` - Database connection and query utilities
|
- `database/connection.py` - Database connection and query utilities
|
||||||
- `data/okx_collector.py` - OKX API integration for real-time market data collection
|
- `data/okx_collector.py` - OKX API integration for real-time market data collection
|
||||||
- `data/aggregator.py` - OHLCV candle aggregation and processing
|
- `data/aggregator.py` - OHLCV candle aggregation and processing
|
||||||
@ -16,7 +17,7 @@
|
|||||||
- `config/strategies/` - Directory for JSON strategy parameter files
|
- `config/strategies/` - Directory for JSON strategy parameter files
|
||||||
- `scripts/dev.py` - Development setup and management script
|
- `scripts/dev.py` - Development setup and management script
|
||||||
- `requirements.txt` - Python dependencies managed by UV
|
- `requirements.txt` - Python dependencies managed by UV
|
||||||
- `docker-compose.yml` - Docker services configuration
|
- `docker-compose.yml` - Docker services configuration with TimescaleDB support
|
||||||
- `tests/test_strategies.py` - Unit tests for strategy implementations
|
- `tests/test_strategies.py` - Unit tests for strategy implementations
|
||||||
- `tests/test_bot_manager.py` - Unit tests for bot management functionality
|
- `tests/test_bot_manager.py` - Unit tests for bot management functionality
|
||||||
- `tests/test_data_collection.py` - Unit tests for data collection and aggregation
|
- `tests/test_data_collection.py` - Unit tests for data collection and aggregation
|
||||||
@ -33,10 +34,10 @@
|
|||||||
|
|
||||||
- [ ] 1.0 Database Foundation and Schema Setup
|
- [ ] 1.0 Database Foundation and Schema Setup
|
||||||
- [x] 1.1 Install and configure PostgreSQL with Docker
|
- [x] 1.1 Install and configure PostgreSQL with Docker
|
||||||
- [ ] 1.2 Create database schema following the PRD specifications (market_data, bots, signals, trades, bot_performance tables)
|
- [x] 1.2 Create database schema following the PRD specifications (market_data, bots, signals, trades, bot_performance tables)
|
||||||
- [ ] 1.3 Implement database connection utility with connection pooling
|
- [ ] 1.3 Implement database connection utility with connection pooling
|
||||||
- [ ] 1.4 Create database models using SQLAlchemy or similar ORM
|
- [ ] 1.4 Create database models using SQLAlchemy or similar ORM
|
||||||
- [ ] 1.5 Add proper indexes for time-series data optimization
|
- [x] 1.5 Add proper indexes for time-series data optimization
|
||||||
- [ ] 1.6 Setup Redis for pub/sub messaging
|
- [ ] 1.6 Setup Redis for pub/sub messaging
|
||||||
- [ ] 1.7 Create database migration scripts and initial data seeding
|
- [ ] 1.7 Create database migration scripts and initial data seeding
|
||||||
- [ ] 1.8 Unit test database models and connection utilities
|
- [ ] 1.8 Unit test database models and connection utilities
|
||||||
@ -150,4 +151,13 @@
|
|||||||
- [ ] 12.6 Prepare for production deployment
|
- [ ] 12.6 Prepare for production deployment
|
||||||
- [ ] 12.7 Create maintenance and support procedures
|
- [ ] 12.7 Create maintenance and support procedures
|
||||||
|
|
||||||
|
- [ ] 13.0 Performance Optimization and Scaling (Future Enhancement)
|
||||||
|
- [ ] 13.1 Implement TimescaleDB hypertables for time-series optimization
|
||||||
|
- [ ] 13.2 Optimize database schema for hypertable compatibility (composite primary keys)
|
||||||
|
- [ ] 13.3 Add database query performance monitoring and analysis
|
||||||
|
- [ ] 13.4 Implement advanced connection pooling optimization
|
||||||
|
- [ ] 13.5 Add caching layer for frequently accessed market data
|
||||||
|
- [ ] 13.6 Optimize data retention and archival strategies
|
||||||
|
- [ ] 13.7 Implement horizontal scaling for high-volume trading scenarios
|
||||||
|
|
||||||
|
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user