Initial project structure: MarketScanner - Fear-to-Fortune Trading Intelligence
Features: - FastAPI backend with stocks, news, signals, watchlist, analytics endpoints - React frontend with TailwindCSS dark mode trading dashboard - Celery workers for news fetching, sentiment analysis, pattern detection - TimescaleDB schema for time-series stock data - Docker Compose setup for all services - OpenAI integration for sentiment analysis
This commit is contained in:
343
docker/db/init.sql
Normal file
343
docker/db/init.sql
Normal file
@@ -0,0 +1,343 @@
|
||||
-- MarketScanner Database Initialization
|
||||
-- TimescaleDB + PostgreSQL
|
||||
|
||||
-- Enable TimescaleDB extension
|
||||
CREATE EXTENSION IF NOT EXISTS timescaledb;
|
||||
|
||||
-- Enable UUID extension
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
|
||||
-- Enable pg_trgm for text search
|
||||
CREATE EXTENSION IF NOT EXISTS pg_trgm;
|
||||
|
||||
-- =============================================================================
|
||||
-- STOCKS TABLE
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS stocks (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
symbol VARCHAR(20) NOT NULL UNIQUE,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
sector VARCHAR(100),
|
||||
industry VARCHAR(100),
|
||||
market_cap BIGINT,
|
||||
exchange VARCHAR(50),
|
||||
country VARCHAR(100) DEFAULT 'USA',
|
||||
is_active BOOLEAN DEFAULT true,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_stocks_symbol ON stocks(symbol);
|
||||
CREATE INDEX idx_stocks_sector ON stocks(sector);
|
||||
CREATE INDEX idx_stocks_industry ON stocks(industry);
|
||||
|
||||
-- =============================================================================
|
||||
-- STOCK PRICES (Time-series)
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS stock_prices (
|
||||
time TIMESTAMPTZ NOT NULL,
|
||||
stock_id UUID NOT NULL REFERENCES stocks(id) ON DELETE CASCADE,
|
||||
open DECIMAL(15, 4),
|
||||
high DECIMAL(15, 4),
|
||||
low DECIMAL(15, 4),
|
||||
close DECIMAL(15, 4) NOT NULL,
|
||||
volume BIGINT,
|
||||
adjusted_close DECIMAL(15, 4),
|
||||
PRIMARY KEY (time, stock_id)
|
||||
);
|
||||
|
||||
-- Convert to hypertable for time-series optimization
|
||||
SELECT create_hypertable('stock_prices', 'time', if_not_exists => TRUE);
|
||||
|
||||
-- Create indexes
|
||||
CREATE INDEX idx_stock_prices_stock_id ON stock_prices(stock_id, time DESC);
|
||||
|
||||
-- =============================================================================
|
||||
-- NEWS ARTICLES
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS news_articles (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
title TEXT NOT NULL,
|
||||
content TEXT,
|
||||
summary TEXT,
|
||||
url TEXT UNIQUE NOT NULL,
|
||||
source VARCHAR(100) NOT NULL,
|
||||
author VARCHAR(255),
|
||||
published_at TIMESTAMPTZ NOT NULL,
|
||||
fetched_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
image_url TEXT,
|
||||
|
||||
-- Sentiment analysis results
|
||||
sentiment_score DECIMAL(5, 2), -- -100 to +100
|
||||
sentiment_label VARCHAR(20), -- negative, neutral, positive
|
||||
sentiment_confidence DECIMAL(5, 4),
|
||||
|
||||
-- Processing status
|
||||
is_processed BOOLEAN DEFAULT false,
|
||||
processing_error TEXT
|
||||
);
|
||||
|
||||
CREATE INDEX idx_news_published_at ON news_articles(published_at DESC);
|
||||
CREATE INDEX idx_news_source ON news_articles(source);
|
||||
CREATE INDEX idx_news_sentiment ON news_articles(sentiment_score);
|
||||
CREATE INDEX idx_news_title_trgm ON news_articles USING gin(title gin_trgm_ops);
|
||||
|
||||
-- =============================================================================
|
||||
-- NEWS-STOCK ASSOCIATIONS
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS news_stock_mentions (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
news_id UUID NOT NULL REFERENCES news_articles(id) ON DELETE CASCADE,
|
||||
stock_id UUID NOT NULL REFERENCES stocks(id) ON DELETE CASCADE,
|
||||
mention_type VARCHAR(50), -- direct, indirect, sector
|
||||
relevance_score DECIMAL(5, 4),
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
UNIQUE(news_id, stock_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_mentions_news ON news_stock_mentions(news_id);
|
||||
CREATE INDEX idx_mentions_stock ON news_stock_mentions(stock_id);
|
||||
|
||||
-- =============================================================================
|
||||
-- PANIC EVENTS
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS panic_events (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
stock_id UUID NOT NULL REFERENCES stocks(id) ON DELETE CASCADE,
|
||||
|
||||
-- Event timing
|
||||
start_time TIMESTAMPTZ NOT NULL,
|
||||
peak_time TIMESTAMPTZ,
|
||||
end_time TIMESTAMPTZ,
|
||||
|
||||
-- Price impact
|
||||
price_at_start DECIMAL(15, 4) NOT NULL,
|
||||
price_at_peak_panic DECIMAL(15, 4),
|
||||
price_at_end DECIMAL(15, 4),
|
||||
max_drawdown_percent DECIMAL(8, 4),
|
||||
|
||||
-- Sentiment
|
||||
avg_sentiment_score DECIMAL(5, 2),
|
||||
min_sentiment_score DECIMAL(5, 2),
|
||||
news_volume INTEGER,
|
||||
|
||||
-- Recovery metrics
|
||||
recovery_time_days INTEGER,
|
||||
recovery_percent DECIMAL(8, 4),
|
||||
|
||||
-- Classification
|
||||
event_type VARCHAR(100), -- earnings_miss, scandal, lawsuit, macro, etc.
|
||||
event_category VARCHAR(50), -- company_specific, sector_wide, market_wide
|
||||
|
||||
-- Analysis
|
||||
is_complete BOOLEAN DEFAULT false,
|
||||
notes TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_panic_stock ON panic_events(stock_id);
|
||||
CREATE INDEX idx_panic_time ON panic_events(start_time DESC);
|
||||
CREATE INDEX idx_panic_type ON panic_events(event_type);
|
||||
CREATE INDEX idx_panic_drawdown ON panic_events(max_drawdown_percent);
|
||||
|
||||
-- =============================================================================
|
||||
-- HISTORICAL PATTERNS
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS historical_patterns (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
stock_id UUID NOT NULL REFERENCES stocks(id) ON DELETE CASCADE,
|
||||
|
||||
-- Pattern definition
|
||||
pattern_type VARCHAR(100) NOT NULL, -- earnings_miss_recovery, scandal_recovery, etc.
|
||||
|
||||
-- Statistics (aggregated from multiple panic events)
|
||||
avg_drawdown_percent DECIMAL(8, 4),
|
||||
avg_recovery_days INTEGER,
|
||||
avg_recovery_percent DECIMAL(8, 4),
|
||||
|
||||
median_drawdown_percent DECIMAL(8, 4),
|
||||
median_recovery_days INTEGER,
|
||||
median_recovery_percent DECIMAL(8, 4),
|
||||
|
||||
-- Sample size
|
||||
event_count INTEGER NOT NULL,
|
||||
|
||||
-- Confidence
|
||||
pattern_confidence DECIMAL(5, 4),
|
||||
|
||||
-- Time range
|
||||
first_event_date DATE,
|
||||
last_event_date DATE,
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
|
||||
UNIQUE(stock_id, pattern_type)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_patterns_stock ON historical_patterns(stock_id);
|
||||
CREATE INDEX idx_patterns_type ON historical_patterns(pattern_type);
|
||||
|
||||
-- =============================================================================
|
||||
-- BUY SIGNALS
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS buy_signals (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
stock_id UUID NOT NULL REFERENCES stocks(id) ON DELETE CASCADE,
|
||||
panic_event_id UUID REFERENCES panic_events(id) ON DELETE SET NULL,
|
||||
|
||||
-- Signal details
|
||||
signal_time TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
signal_price DECIMAL(15, 4) NOT NULL,
|
||||
|
||||
-- Confidence scoring
|
||||
confidence_score DECIMAL(5, 4) NOT NULL, -- 0 to 1
|
||||
|
||||
-- Based on pattern
|
||||
pattern_id UUID REFERENCES historical_patterns(id) ON DELETE SET NULL,
|
||||
expected_recovery_percent DECIMAL(8, 4),
|
||||
expected_recovery_days INTEGER,
|
||||
|
||||
-- Current metrics
|
||||
current_drawdown_percent DECIMAL(8, 4),
|
||||
current_sentiment_score DECIMAL(5, 2),
|
||||
|
||||
-- Signal status
|
||||
status VARCHAR(20) DEFAULT 'active', -- active, triggered, expired, cancelled
|
||||
triggered_at TIMESTAMPTZ,
|
||||
|
||||
-- Outcome tracking
|
||||
outcome_price DECIMAL(15, 4),
|
||||
outcome_percent DECIMAL(8, 4),
|
||||
outcome_days INTEGER,
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_signals_stock ON buy_signals(stock_id);
|
||||
CREATE INDEX idx_signals_time ON buy_signals(signal_time DESC);
|
||||
CREATE INDEX idx_signals_confidence ON buy_signals(confidence_score DESC);
|
||||
CREATE INDEX idx_signals_status ON buy_signals(status);
|
||||
|
||||
-- =============================================================================
|
||||
-- WATCHLIST
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS watchlist (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
stock_id UUID NOT NULL REFERENCES stocks(id) ON DELETE CASCADE,
|
||||
|
||||
-- Alert thresholds
|
||||
panic_alert_threshold DECIMAL(5, 2) DEFAULT -50,
|
||||
price_alert_low DECIMAL(15, 4),
|
||||
price_alert_high DECIMAL(15, 4),
|
||||
|
||||
-- Preferences
|
||||
priority INTEGER DEFAULT 1, -- 1 = high, 2 = medium, 3 = low
|
||||
notes TEXT,
|
||||
|
||||
is_active BOOLEAN DEFAULT true,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
|
||||
UNIQUE(stock_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_watchlist_priority ON watchlist(priority, is_active);
|
||||
|
||||
-- =============================================================================
|
||||
-- ALERT HISTORY
|
||||
-- =============================================================================
|
||||
CREATE TABLE IF NOT EXISTS alert_history (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
stock_id UUID NOT NULL REFERENCES stocks(id) ON DELETE CASCADE,
|
||||
signal_id UUID REFERENCES buy_signals(id) ON DELETE SET NULL,
|
||||
|
||||
alert_type VARCHAR(50) NOT NULL, -- panic_detected, buy_signal, price_target, etc.
|
||||
alert_message TEXT NOT NULL,
|
||||
|
||||
-- Delivery status
|
||||
sent_telegram BOOLEAN DEFAULT false,
|
||||
sent_discord BOOLEAN DEFAULT false,
|
||||
sent_email BOOLEAN DEFAULT false,
|
||||
|
||||
created_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_alerts_time ON alert_history(created_at DESC);
|
||||
CREATE INDEX idx_alerts_stock ON alert_history(stock_id);
|
||||
|
||||
-- =============================================================================
|
||||
-- FUNCTIONS
|
||||
-- =============================================================================
|
||||
|
||||
-- Function to update updated_at timestamp
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ language 'plpgsql';
|
||||
|
||||
-- Apply triggers
|
||||
CREATE TRIGGER update_stocks_updated_at BEFORE UPDATE ON stocks FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
CREATE TRIGGER update_panic_events_updated_at BEFORE UPDATE ON panic_events FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
CREATE TRIGGER update_patterns_updated_at BEFORE UPDATE ON historical_patterns FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
CREATE TRIGGER update_signals_updated_at BEFORE UPDATE ON buy_signals FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
CREATE TRIGGER update_watchlist_updated_at BEFORE UPDATE ON watchlist FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- =============================================================================
|
||||
-- SEED DATA - Popular stocks to get started
|
||||
-- =============================================================================
|
||||
INSERT INTO stocks (symbol, name, sector, industry, exchange) VALUES
|
||||
('AAPL', 'Apple Inc.', 'Technology', 'Consumer Electronics', 'NASDAQ'),
|
||||
('MSFT', 'Microsoft Corporation', 'Technology', 'Software', 'NASDAQ'),
|
||||
('GOOGL', 'Alphabet Inc.', 'Technology', 'Internet Services', 'NASDAQ'),
|
||||
('AMZN', 'Amazon.com Inc.', 'Consumer Discretionary', 'E-Commerce', 'NASDAQ'),
|
||||
('NVDA', 'NVIDIA Corporation', 'Technology', 'Semiconductors', 'NASDAQ'),
|
||||
('META', 'Meta Platforms Inc.', 'Technology', 'Social Media', 'NASDAQ'),
|
||||
('TSLA', 'Tesla Inc.', 'Consumer Discretionary', 'Electric Vehicles', 'NASDAQ'),
|
||||
('JPM', 'JPMorgan Chase & Co.', 'Financials', 'Banking', 'NYSE'),
|
||||
('V', 'Visa Inc.', 'Financials', 'Payments', 'NYSE'),
|
||||
('JNJ', 'Johnson & Johnson', 'Healthcare', 'Pharmaceuticals', 'NYSE'),
|
||||
('WMT', 'Walmart Inc.', 'Consumer Staples', 'Retail', 'NYSE'),
|
||||
('XOM', 'Exxon Mobil Corporation', 'Energy', 'Oil & Gas', 'NYSE'),
|
||||
('BA', 'Boeing Company', 'Industrials', 'Aerospace', 'NYSE'),
|
||||
('DIS', 'Walt Disney Company', 'Communication Services', 'Entertainment', 'NYSE'),
|
||||
('NFLX', 'Netflix Inc.', 'Communication Services', 'Streaming', 'NASDAQ'),
|
||||
('AMD', 'Advanced Micro Devices', 'Technology', 'Semiconductors', 'NASDAQ'),
|
||||
('INTC', 'Intel Corporation', 'Technology', 'Semiconductors', 'NASDAQ'),
|
||||
('CRM', 'Salesforce Inc.', 'Technology', 'Software', 'NYSE'),
|
||||
('ORCL', 'Oracle Corporation', 'Technology', 'Software', 'NYSE'),
|
||||
('PYPL', 'PayPal Holdings Inc.', 'Financials', 'Payments', 'NASDAQ'),
|
||||
-- Defense & Weapons (no morals, remember?)
|
||||
('LMT', 'Lockheed Martin Corporation', 'Industrials', 'Defense', 'NYSE'),
|
||||
('RTX', 'RTX Corporation', 'Industrials', 'Defense', 'NYSE'),
|
||||
('NOC', 'Northrop Grumman Corporation', 'Industrials', 'Defense', 'NYSE'),
|
||||
('GD', 'General Dynamics Corporation', 'Industrials', 'Defense', 'NYSE'),
|
||||
('BA', 'Boeing Company', 'Industrials', 'Aerospace & Defense', 'NYSE'),
|
||||
-- Mining
|
||||
('NEM', 'Newmont Corporation', 'Materials', 'Gold Mining', 'NYSE'),
|
||||
('FCX', 'Freeport-McMoRan Inc.', 'Materials', 'Copper Mining', 'NYSE'),
|
||||
('RIO', 'Rio Tinto Group', 'Materials', 'Diversified Mining', 'NYSE'),
|
||||
('BHP', 'BHP Group Limited', 'Materials', 'Diversified Mining', 'NYSE'),
|
||||
-- Food & Agriculture
|
||||
('ADM', 'Archer-Daniels-Midland Company', 'Consumer Staples', 'Agriculture', 'NYSE'),
|
||||
('BG', 'Bunge Limited', 'Consumer Staples', 'Agriculture', 'NYSE'),
|
||||
('MDLZ', 'Mondelez International', 'Consumer Staples', 'Food', 'NASDAQ'),
|
||||
('KO', 'Coca-Cola Company', 'Consumer Staples', 'Beverages', 'NYSE'),
|
||||
('PEP', 'PepsiCo Inc.', 'Consumer Staples', 'Beverages', 'NASDAQ'),
|
||||
-- Oil & Gas
|
||||
('CVX', 'Chevron Corporation', 'Energy', 'Oil & Gas', 'NYSE'),
|
||||
('COP', 'ConocoPhillips', 'Energy', 'Oil & Gas', 'NYSE'),
|
||||
('SLB', 'Schlumberger Limited', 'Energy', 'Oil Services', 'NYSE'),
|
||||
-- Pharma & Biotech
|
||||
('PFE', 'Pfizer Inc.', 'Healthcare', 'Pharmaceuticals', 'NYSE'),
|
||||
('MRK', 'Merck & Co. Inc.', 'Healthcare', 'Pharmaceuticals', 'NYSE'),
|
||||
('ABBV', 'AbbVie Inc.', 'Healthcare', 'Pharmaceuticals', 'NYSE'),
|
||||
('BMY', 'Bristol-Myers Squibb', 'Healthcare', 'Pharmaceuticals', 'NYSE')
|
||||
ON CONFLICT (symbol) DO NOTHING;
|
||||
|
||||
COMMIT;
|
||||
Reference in New Issue
Block a user