214 lines
7.8 KiB
SQL
214 lines
7.8 KiB
SQL
-- Initialize TimescaleDB extension and create market data schema
|
|
CREATE EXTENSION IF NOT EXISTS timescaledb;
|
|
|
|
-- Create database schema for market data
|
|
CREATE SCHEMA IF NOT EXISTS market_data;
|
|
|
|
-- Set search path
|
|
SET search_path TO market_data, public;
|
|
|
|
-- Order book snapshots table
|
|
CREATE TABLE IF NOT EXISTS 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)
|
|
);
|
|
|
|
-- Convert to hypertable
|
|
SELECT create_hypertable('order_book_snapshots', 'timestamp', if_not_exists => TRUE);
|
|
|
|
-- Create indexes for better query performance
|
|
CREATE INDEX IF NOT EXISTS idx_order_book_symbol_exchange ON order_book_snapshots (symbol, exchange, timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_order_book_timestamp ON order_book_snapshots (timestamp DESC);
|
|
|
|
-- Trade events table
|
|
CREATE TABLE IF NOT EXISTS 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)
|
|
);
|
|
|
|
-- Convert to hypertable
|
|
SELECT create_hypertable('trade_events', 'timestamp', if_not_exists => TRUE);
|
|
|
|
-- Create indexes for trade events
|
|
CREATE INDEX IF NOT EXISTS idx_trade_events_symbol_exchange ON trade_events (symbol, exchange, timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_trade_events_timestamp ON trade_events (timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_trade_events_price ON trade_events (symbol, price, timestamp DESC);
|
|
|
|
-- Aggregated heatmap data table
|
|
CREATE TABLE IF NOT EXISTS 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)
|
|
);
|
|
|
|
-- Convert to hypertable
|
|
SELECT create_hypertable('heatmap_data', 'timestamp', if_not_exists => TRUE);
|
|
|
|
-- Create indexes for heatmap data
|
|
CREATE INDEX IF NOT EXISTS idx_heatmap_symbol_bucket ON heatmap_data (symbol, bucket_size, timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_heatmap_timestamp ON heatmap_data (timestamp DESC);
|
|
|
|
-- OHLCV data table
|
|
CREATE TABLE IF NOT EXISTS 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)
|
|
);
|
|
|
|
-- Convert to hypertable
|
|
SELECT create_hypertable('ohlcv_data', 'timestamp', if_not_exists => TRUE);
|
|
|
|
-- Create indexes for OHLCV data
|
|
CREATE INDEX IF NOT EXISTS idx_ohlcv_symbol_timeframe ON ohlcv_data (symbol, timeframe, timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_ohlcv_timestamp ON ohlcv_data (timestamp DESC);
|
|
|
|
-- Exchange status tracking table
|
|
CREATE TABLE IF NOT EXISTS exchange_status (
|
|
exchange VARCHAR(20) NOT NULL,
|
|
timestamp TIMESTAMPTZ NOT NULL,
|
|
status VARCHAR(20) NOT NULL, -- 'connected', 'disconnected', 'error'
|
|
last_message_time TIMESTAMPTZ,
|
|
error_message TEXT,
|
|
connection_count INTEGER DEFAULT 0,
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
PRIMARY KEY (timestamp, exchange)
|
|
);
|
|
|
|
-- Convert to hypertable
|
|
SELECT create_hypertable('exchange_status', 'timestamp', if_not_exists => TRUE);
|
|
|
|
-- Create indexes for exchange status
|
|
CREATE INDEX IF NOT EXISTS idx_exchange_status_exchange ON exchange_status (exchange, timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_exchange_status_timestamp ON exchange_status (timestamp DESC);
|
|
|
|
-- System metrics table for monitoring
|
|
CREATE TABLE IF NOT EXISTS 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)
|
|
);
|
|
|
|
-- Convert to hypertable
|
|
SELECT create_hypertable('system_metrics', 'timestamp', if_not_exists => TRUE);
|
|
|
|
-- Create indexes for system metrics
|
|
CREATE INDEX IF NOT EXISTS idx_system_metrics_name ON system_metrics (metric_name, timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_system_metrics_timestamp ON system_metrics (timestamp DESC);
|
|
|
|
-- Create retention policies (keep data for 90 days by default)
|
|
SELECT add_retention_policy('order_book_snapshots', INTERVAL '90 days', if_not_exists => TRUE);
|
|
SELECT add_retention_policy('trade_events', INTERVAL '90 days', if_not_exists => TRUE);
|
|
SELECT add_retention_policy('heatmap_data', INTERVAL '90 days', if_not_exists => TRUE);
|
|
SELECT add_retention_policy('ohlcv_data', INTERVAL '365 days', if_not_exists => TRUE);
|
|
SELECT add_retention_policy('exchange_status', INTERVAL '30 days', if_not_exists => TRUE);
|
|
SELECT add_retention_policy('system_metrics', INTERVAL '30 days', if_not_exists => TRUE);
|
|
|
|
-- Create continuous aggregates for common queries
|
|
CREATE MATERIALIZED VIEW IF NOT EXISTS 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 trade_events
|
|
GROUP BY symbol, exchange, hour
|
|
WITH NO DATA;
|
|
|
|
-- Add refresh policy for continuous aggregate
|
|
SELECT add_continuous_aggregate_policy('hourly_ohlcv',
|
|
start_offset => INTERVAL '3 hours',
|
|
end_offset => INTERVAL '1 hour',
|
|
schedule_interval => INTERVAL '1 hour',
|
|
if_not_exists => TRUE);
|
|
|
|
-- Create view for latest order book data
|
|
CREATE OR REPLACE VIEW latest_order_books AS
|
|
SELECT DISTINCT ON (symbol, exchange)
|
|
symbol,
|
|
exchange,
|
|
timestamp,
|
|
bids,
|
|
asks,
|
|
mid_price,
|
|
spread,
|
|
bid_volume,
|
|
ask_volume
|
|
FROM order_book_snapshots
|
|
ORDER BY symbol, exchange, timestamp DESC;
|
|
|
|
-- Create view for latest heatmap data
|
|
CREATE OR REPLACE VIEW latest_heatmaps AS
|
|
SELECT DISTINCT ON (symbol, bucket_size, price_bucket, side)
|
|
symbol,
|
|
bucket_size,
|
|
price_bucket,
|
|
side,
|
|
timestamp,
|
|
volume,
|
|
exchange_count,
|
|
exchanges
|
|
FROM heatmap_data
|
|
ORDER BY symbol, bucket_size, price_bucket, side, timestamp DESC;
|
|
|
|
-- Grant permissions to market_user
|
|
GRANT ALL PRIVILEGES ON SCHEMA market_data TO market_user;
|
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA market_data TO market_user;
|
|
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA market_data TO market_user;
|
|
GRANT ALL PRIVILEGES ON ALL FUNCTIONS IN SCHEMA market_data TO market_user;
|
|
|
|
-- Set default privileges for future objects
|
|
ALTER DEFAULT PRIVILEGES IN SCHEMA market_data GRANT ALL ON TABLES TO market_user;
|
|
ALTER DEFAULT PRIVILEGES IN SCHEMA market_data GRANT ALL ON SEQUENCES TO market_user;
|
|
ALTER DEFAULT PRIVILEGES IN SCHEMA market_data GRANT ALL ON FUNCTIONS TO market_user;
|
|
|
|
-- Create database user for read-only access (for dashboards)
|
|
CREATE USER IF NOT EXISTS dashboard_user WITH PASSWORD 'dashboard_read_2024';
|
|
GRANT CONNECT ON DATABASE market_data TO dashboard_user;
|
|
GRANT USAGE ON SCHEMA market_data TO dashboard_user;
|
|
GRANT SELECT ON ALL TABLES IN SCHEMA market_data TO dashboard_user;
|
|
ALTER DEFAULT PRIVILEGES IN SCHEMA market_data GRANT SELECT ON TABLES TO dashboard_user; |