-- MEV Bot Database Initialization Script -- Creates necessary tables for opportunity persistence -- Arbitrage opportunities table CREATE TABLE IF NOT EXISTS arbitrage_opportunities ( id TEXT PRIMARY KEY, path TEXT NOT NULL, pools TEXT, amount_in BIGINT NOT NULL, profit BIGINT NOT NULL, net_profit BIGINT NOT NULL, gas_estimate BIGINT NOT NULL, gas_cost BIGINT NOT NULL, estimated_profit BIGINT NOT NULL, required_amount BIGINT NOT NULL, roi REAL NOT NULL, protocol TEXT, execution_time INTEGER, confidence REAL, price_impact REAL, max_slippage REAL, token_in TEXT NOT NULL, token_out TEXT NOT NULL, timestamp BIGINT NOT NULL, detected_at TIMESTAMP NOT NULL, expires_at TIMESTAMP NOT NULL, urgency INTEGER, risk REAL, profitable BOOLEAN, executed BOOLEAN DEFAULT FALSE, execution_tx_hash TEXT, execution_status TEXT, execution_gas_used BIGINT, execution_profit BIGINT, execution_error TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Index for fast lookups CREATE INDEX IF NOT EXISTS idx_opportunities_timestamp ON arbitrage_opportunities(timestamp DESC); CREATE INDEX IF NOT EXISTS idx_opportunities_profitable ON arbitrage_opportunities(profitable, profit DESC); CREATE INDEX IF NOT EXISTS idx_opportunities_executed ON arbitrage_opportunities(executed, timestamp DESC); CREATE INDEX IF NOT EXISTS idx_opportunities_token_pair ON arbitrage_opportunities(token_in, token_out); -- Execution history table CREATE TABLE IF NOT EXISTS execution_history ( id SERIAL PRIMARY KEY, opportunity_id TEXT NOT NULL REFERENCES arbitrage_opportunities(id), tx_hash TEXT UNIQUE, block_number BIGINT, status TEXT NOT NULL, gas_used BIGINT, gas_price BIGINT, actual_profit BIGINT, error_message TEXT, executed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_execution_history_opportunity ON execution_history(opportunity_id); CREATE INDEX IF NOT EXISTS idx_execution_history_status ON execution_history(status, executed_at DESC); -- Statistics table for tracking performance CREATE TABLE IF NOT EXISTS bot_statistics ( id SERIAL PRIMARY KEY, opportunities_detected INTEGER DEFAULT 0, opportunities_executed INTEGER DEFAULT 0, total_profit_wei BIGINT DEFAULT 0, total_gas_cost_wei BIGINT DEFAULT 0, success_rate REAL DEFAULT 0, average_roi REAL DEFAULT 0, period_start TIMESTAMP NOT NULL, period_end TIMESTAMP NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Pool cache table CREATE TABLE IF NOT EXISTS pool_cache ( address TEXT PRIMARY KEY, token0 TEXT NOT NULL, token1 TEXT NOT NULL, fee INTEGER, protocol TEXT NOT NULL, liquidity BIGINT, reserve0 BIGINT, reserve1 BIGINT, last_updated TIMESTAMP NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_pool_cache_tokens ON pool_cache(token0, token1); CREATE INDEX IF NOT EXISTS idx_pool_cache_protocol ON pool_cache(protocol); -- Market events table for historical analysis CREATE TABLE IF NOT EXISTS market_events ( id SERIAL PRIMARY KEY, event_type TEXT NOT NULL, pool_address TEXT NOT NULL, token_in TEXT NOT NULL, token_out TEXT NOT NULL, amount_in BIGINT NOT NULL, amount_out BIGINT NOT NULL, price_impact REAL, tx_hash TEXT NOT NULL, block_number BIGINT NOT NULL, timestamp TIMESTAMP NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_market_events_pool ON market_events(pool_address, timestamp DESC); CREATE INDEX IF NOT EXISTS idx_market_events_tokens ON market_events(token_in, token_out); CREATE INDEX IF NOT EXISTS idx_market_events_timestamp ON market_events(timestamp DESC); COMMENT ON TABLE arbitrage_opportunities IS 'Stores detected arbitrage opportunities for analysis and execution tracking'; COMMENT ON TABLE execution_history IS 'Tracks execution attempts and results for all opportunities'; COMMENT ON TABLE bot_statistics IS 'Aggregated performance metrics over time periods'; COMMENT ON TABLE pool_cache IS 'Cached pool data to reduce RPC calls'; COMMENT ON TABLE market_events IS 'Historical market events for analysis and pattern detection';