cob integration scaffold
This commit is contained in:
256
COBY/storage/schema.py
Normal file
256
COBY/storage/schema.py
Normal file
@ -0,0 +1,256 @@
|
||||
"""
|
||||
Database schema management for TimescaleDB.
|
||||
"""
|
||||
|
||||
from typing import List
|
||||
from ..utils.logging import get_logger
|
||||
|
||||
logger = get_logger(__name__)
|
||||
|
||||
|
||||
class DatabaseSchema:
|
||||
"""Manages database schema creation and migrations"""
|
||||
|
||||
@staticmethod
|
||||
def get_schema_creation_queries() -> List[str]:
|
||||
"""Get list of queries to create the database schema"""
|
||||
return [
|
||||
# Create TimescaleDB extension
|
||||
"CREATE EXTENSION IF NOT EXISTS timescaledb;",
|
||||
|
||||
# Create schema
|
||||
"CREATE SCHEMA IF NOT EXISTS market_data;",
|
||||
|
||||
# Order book snapshots table
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS market_data.order_book_snapshots (
|
||||
id BIGSERIAL,
|
||||
symbol VARCHAR(20) NOT NULL,
|
||||
exchange VARCHAR(20) NOT NULL,
|
||||
timestamp TIMESTAMPTZ NOT NULL,
|
||||
bids JSONB NOT NULL,
|
||||
asks JSONB NOT NULL,
|
||||
sequence_id BIGINT,
|
||||
mid_price DECIMAL(20,8),
|
||||
spread DECIMAL(20,8),
|
||||
bid_volume DECIMAL(30,8),
|
||||
ask_volume DECIMAL(30,8),
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
PRIMARY KEY (timestamp, symbol, exchange)
|
||||
);
|
||||
""",
|
||||
|
||||
# Trade events table
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS market_data.trade_events (
|
||||
id BIGSERIAL,
|
||||
symbol VARCHAR(20) NOT NULL,
|
||||
exchange VARCHAR(20) NOT NULL,
|
||||
timestamp TIMESTAMPTZ NOT NULL,
|
||||
price DECIMAL(20,8) NOT NULL,
|
||||
size DECIMAL(30,8) NOT NULL,
|
||||
side VARCHAR(4) NOT NULL,
|
||||
trade_id VARCHAR(100) NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
PRIMARY KEY (timestamp, symbol, exchange, trade_id)
|
||||
);
|
||||
""",
|
||||
|
||||
# Aggregated heatmap data table
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS market_data.heatmap_data (
|
||||
symbol VARCHAR(20) NOT NULL,
|
||||
timestamp TIMESTAMPTZ NOT NULL,
|
||||
bucket_size DECIMAL(10,2) NOT NULL,
|
||||
price_bucket DECIMAL(20,8) NOT NULL,
|
||||
volume DECIMAL(30,8) NOT NULL,
|
||||
side VARCHAR(3) NOT NULL,
|
||||
exchange_count INTEGER NOT NULL,
|
||||
exchanges JSONB,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
PRIMARY KEY (timestamp, symbol, bucket_size, price_bucket, side)
|
||||
);
|
||||
""",
|
||||
|
||||
# OHLCV data table
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS market_data.ohlcv_data (
|
||||
symbol VARCHAR(20) NOT NULL,
|
||||
timestamp TIMESTAMPTZ NOT NULL,
|
||||
timeframe VARCHAR(10) NOT NULL,
|
||||
open_price DECIMAL(20,8) NOT NULL,
|
||||
high_price DECIMAL(20,8) NOT NULL,
|
||||
low_price DECIMAL(20,8) NOT NULL,
|
||||
close_price DECIMAL(20,8) NOT NULL,
|
||||
volume DECIMAL(30,8) NOT NULL,
|
||||
trade_count INTEGER,
|
||||
vwap DECIMAL(20,8),
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
PRIMARY KEY (timestamp, symbol, timeframe)
|
||||
);
|
||||
""",
|
||||
|
||||
# Exchange status tracking table
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS market_data.exchange_status (
|
||||
exchange VARCHAR(20) NOT NULL,
|
||||
timestamp TIMESTAMPTZ NOT NULL,
|
||||
status VARCHAR(20) NOT NULL,
|
||||
last_message_time TIMESTAMPTZ,
|
||||
error_message TEXT,
|
||||
connection_count INTEGER DEFAULT 0,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
PRIMARY KEY (timestamp, exchange)
|
||||
);
|
||||
""",
|
||||
|
||||
# System metrics table
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS market_data.system_metrics (
|
||||
metric_name VARCHAR(50) NOT NULL,
|
||||
timestamp TIMESTAMPTZ NOT NULL,
|
||||
value DECIMAL(20,8) NOT NULL,
|
||||
labels JSONB,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
PRIMARY KEY (timestamp, metric_name)
|
||||
);
|
||||
"""
|
||||
]
|
||||
|
||||
@staticmethod
|
||||
def get_hypertable_creation_queries() -> List[str]:
|
||||
"""Get queries to create hypertables"""
|
||||
return [
|
||||
"SELECT create_hypertable('market_data.order_book_snapshots', 'timestamp', if_not_exists => TRUE);",
|
||||
"SELECT create_hypertable('market_data.trade_events', 'timestamp', if_not_exists => TRUE);",
|
||||
"SELECT create_hypertable('market_data.heatmap_data', 'timestamp', if_not_exists => TRUE);",
|
||||
"SELECT create_hypertable('market_data.ohlcv_data', 'timestamp', if_not_exists => TRUE);",
|
||||
"SELECT create_hypertable('market_data.exchange_status', 'timestamp', if_not_exists => TRUE);",
|
||||
"SELECT create_hypertable('market_data.system_metrics', 'timestamp', if_not_exists => TRUE);"
|
||||
]
|
||||
|
||||
@staticmethod
|
||||
def get_index_creation_queries() -> List[str]:
|
||||
"""Get queries to create indexes"""
|
||||
return [
|
||||
# Order book indexes
|
||||
"CREATE INDEX IF NOT EXISTS idx_order_book_symbol_exchange ON market_data.order_book_snapshots (symbol, exchange, timestamp DESC);",
|
||||
"CREATE INDEX IF NOT EXISTS idx_order_book_timestamp ON market_data.order_book_snapshots (timestamp DESC);",
|
||||
|
||||
# Trade events indexes
|
||||
"CREATE INDEX IF NOT EXISTS idx_trade_events_symbol_exchange ON market_data.trade_events (symbol, exchange, timestamp DESC);",
|
||||
"CREATE INDEX IF NOT EXISTS idx_trade_events_timestamp ON market_data.trade_events (timestamp DESC);",
|
||||
"CREATE INDEX IF NOT EXISTS idx_trade_events_price ON market_data.trade_events (symbol, price, timestamp DESC);",
|
||||
|
||||
# Heatmap data indexes
|
||||
"CREATE INDEX IF NOT EXISTS idx_heatmap_symbol_bucket ON market_data.heatmap_data (symbol, bucket_size, timestamp DESC);",
|
||||
"CREATE INDEX IF NOT EXISTS idx_heatmap_timestamp ON market_data.heatmap_data (timestamp DESC);",
|
||||
|
||||
# OHLCV data indexes
|
||||
"CREATE INDEX IF NOT EXISTS idx_ohlcv_symbol_timeframe ON market_data.ohlcv_data (symbol, timeframe, timestamp DESC);",
|
||||
"CREATE INDEX IF NOT EXISTS idx_ohlcv_timestamp ON market_data.ohlcv_data (timestamp DESC);",
|
||||
|
||||
# Exchange status indexes
|
||||
"CREATE INDEX IF NOT EXISTS idx_exchange_status_exchange ON market_data.exchange_status (exchange, timestamp DESC);",
|
||||
"CREATE INDEX IF NOT EXISTS idx_exchange_status_timestamp ON market_data.exchange_status (timestamp DESC);",
|
||||
|
||||
# System metrics indexes
|
||||
"CREATE INDEX IF NOT EXISTS idx_system_metrics_name ON market_data.system_metrics (metric_name, timestamp DESC);",
|
||||
"CREATE INDEX IF NOT EXISTS idx_system_metrics_timestamp ON market_data.system_metrics (timestamp DESC);"
|
||||
]
|
||||
|
||||
@staticmethod
|
||||
def get_retention_policy_queries() -> List[str]:
|
||||
"""Get queries to create retention policies"""
|
||||
return [
|
||||
"SELECT add_retention_policy('market_data.order_book_snapshots', INTERVAL '90 days', if_not_exists => TRUE);",
|
||||
"SELECT add_retention_policy('market_data.trade_events', INTERVAL '90 days', if_not_exists => TRUE);",
|
||||
"SELECT add_retention_policy('market_data.heatmap_data', INTERVAL '90 days', if_not_exists => TRUE);",
|
||||
"SELECT add_retention_policy('market_data.ohlcv_data', INTERVAL '365 days', if_not_exists => TRUE);",
|
||||
"SELECT add_retention_policy('market_data.exchange_status', INTERVAL '30 days', if_not_exists => TRUE);",
|
||||
"SELECT add_retention_policy('market_data.system_metrics', INTERVAL '30 days', if_not_exists => TRUE);"
|
||||
]
|
||||
|
||||
@staticmethod
|
||||
def get_continuous_aggregate_queries() -> List[str]:
|
||||
"""Get queries to create continuous aggregates"""
|
||||
return [
|
||||
# Hourly OHLCV aggregate
|
||||
"""
|
||||
CREATE MATERIALIZED VIEW IF NOT EXISTS market_data.hourly_ohlcv
|
||||
WITH (timescaledb.continuous) AS
|
||||
SELECT
|
||||
symbol,
|
||||
exchange,
|
||||
time_bucket('1 hour', timestamp) AS hour,
|
||||
first(price, timestamp) AS open_price,
|
||||
max(price) AS high_price,
|
||||
min(price) AS low_price,
|
||||
last(price, timestamp) AS close_price,
|
||||
sum(size) AS volume,
|
||||
count(*) AS trade_count,
|
||||
avg(price) AS vwap
|
||||
FROM market_data.trade_events
|
||||
GROUP BY symbol, exchange, hour
|
||||
WITH NO DATA;
|
||||
""",
|
||||
|
||||
# Add refresh policy for continuous aggregate
|
||||
"""
|
||||
SELECT add_continuous_aggregate_policy('market_data.hourly_ohlcv',
|
||||
start_offset => INTERVAL '3 hours',
|
||||
end_offset => INTERVAL '1 hour',
|
||||
schedule_interval => INTERVAL '1 hour',
|
||||
if_not_exists => TRUE);
|
||||
"""
|
||||
]
|
||||
|
||||
@staticmethod
|
||||
def get_view_creation_queries() -> List[str]:
|
||||
"""Get queries to create views"""
|
||||
return [
|
||||
# Latest order books view
|
||||
"""
|
||||
CREATE OR REPLACE VIEW market_data.latest_order_books AS
|
||||
SELECT DISTINCT ON (symbol, exchange)
|
||||
symbol,
|
||||
exchange,
|
||||
timestamp,
|
||||
bids,
|
||||
asks,
|
||||
mid_price,
|
||||
spread,
|
||||
bid_volume,
|
||||
ask_volume
|
||||
FROM market_data.order_book_snapshots
|
||||
ORDER BY symbol, exchange, timestamp DESC;
|
||||
""",
|
||||
|
||||
# Latest heatmaps view
|
||||
"""
|
||||
CREATE OR REPLACE VIEW market_data.latest_heatmaps AS
|
||||
SELECT DISTINCT ON (symbol, bucket_size, price_bucket, side)
|
||||
symbol,
|
||||
bucket_size,
|
||||
price_bucket,
|
||||
side,
|
||||
timestamp,
|
||||
volume,
|
||||
exchange_count,
|
||||
exchanges
|
||||
FROM market_data.heatmap_data
|
||||
ORDER BY symbol, bucket_size, price_bucket, side, timestamp DESC;
|
||||
"""
|
||||
]
|
||||
|
||||
@staticmethod
|
||||
def get_all_creation_queries() -> List[str]:
|
||||
"""Get all schema creation queries in order"""
|
||||
queries = []
|
||||
queries.extend(DatabaseSchema.get_schema_creation_queries())
|
||||
queries.extend(DatabaseSchema.get_hypertable_creation_queries())
|
||||
queries.extend(DatabaseSchema.get_index_creation_queries())
|
||||
queries.extend(DatabaseSchema.get_retention_policy_queries())
|
||||
queries.extend(DatabaseSchema.get_continuous_aggregate_queries())
|
||||
queries.extend(DatabaseSchema.get_view_creation_queries())
|
||||
return queries
|
Reference in New Issue
Block a user