/* Embedded SQL Schema for C Nostr Relay * Generated from db/schema.sql - Do not edit manually * Schema Version: 3 */ #ifndef SQL_SCHEMA_H #define SQL_SCHEMA_H /* Schema version constant */ #define EMBEDDED_SCHEMA_VERSION "3" /* Embedded SQL schema as C string literal */ static const char* const EMBEDDED_SCHEMA_SQL = "-- C Nostr Relay Database Schema\n\ -- SQLite schema for storing Nostr events with JSON tags support\n\ \n\ -- Schema version tracking\n\ PRAGMA user_version = 3;\n\ \n\ -- Enable foreign key support\n\ PRAGMA foreign_keys = ON;\n\ \n\ -- Optimize for performance\n\ PRAGMA journal_mode = WAL;\n\ PRAGMA synchronous = NORMAL;\n\ PRAGMA cache_size = 10000;\n\ \n\ -- Core events table with hybrid single-table design\n\ CREATE TABLE events (\n\ id TEXT PRIMARY KEY, -- Nostr event ID (hex string)\n\ pubkey TEXT NOT NULL, -- Public key of event author (hex string)\n\ created_at INTEGER NOT NULL, -- Event creation timestamp (Unix timestamp)\n\ kind INTEGER NOT NULL, -- Event kind (0-65535)\n\ event_type TEXT NOT NULL CHECK (event_type IN ('regular', 'replaceable', 'ephemeral', 'addressable')),\n\ content TEXT NOT NULL, -- Event content (text content only)\n\ sig TEXT NOT NULL, -- Event signature (hex string)\n\ tags JSON NOT NULL DEFAULT '[]', -- Event tags as JSON array\n\ first_seen INTEGER NOT NULL DEFAULT (strftime('%s', 'now')) -- When relay received event\n\ );\n\ \n\ -- Core performance indexes\n\ CREATE INDEX idx_events_pubkey ON events(pubkey);\n\ CREATE INDEX idx_events_kind ON events(kind);\n\ CREATE INDEX idx_events_created_at ON events(created_at DESC);\n\ CREATE INDEX idx_events_event_type ON events(event_type);\n\ \n\ -- Composite indexes for common query patterns\n\ CREATE INDEX idx_events_kind_created_at ON events(kind, created_at DESC);\n\ CREATE INDEX idx_events_pubkey_created_at ON events(pubkey, created_at DESC);\n\ CREATE INDEX idx_events_pubkey_kind ON events(pubkey, kind);\n\ \n\ -- Schema information table\n\ CREATE TABLE schema_info (\n\ key TEXT PRIMARY KEY,\n\ value TEXT NOT NULL,\n\ updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))\n\ );\n\ \n\ -- Insert schema metadata\n\ INSERT INTO schema_info (key, value) VALUES\n\ ('version', '3'),\n\ ('description', 'Hybrid single-table Nostr relay schema with JSON tags and configuration management'),\n\ ('created_at', strftime('%s', 'now'));\n\ \n\ -- Helper views for common queries\n\ CREATE VIEW recent_events AS\n\ SELECT id, pubkey, created_at, kind, event_type, content\n\ FROM events\n\ WHERE event_type != 'ephemeral'\n\ ORDER BY created_at DESC\n\ LIMIT 1000;\n\ \n\ CREATE VIEW event_stats AS\n\ SELECT \n\ event_type,\n\ COUNT(*) as count,\n\ AVG(length(content)) as avg_content_length,\n\ MIN(created_at) as earliest,\n\ MAX(created_at) as latest\n\ FROM events\n\ GROUP BY event_type;\n\ \n\ -- Optimization: Trigger for automatic cleanup of ephemeral events older than 1 hour\n\ CREATE TRIGGER cleanup_ephemeral_events\n\ AFTER INSERT ON events\n\ WHEN NEW.event_type = 'ephemeral'\n\ BEGIN\n\ DELETE FROM events \n\ WHERE event_type = 'ephemeral' \n\ AND first_seen < (strftime('%s', 'now') - 3600);\n\ END;\n\ \n\ -- Replaceable event handling trigger\n\ CREATE TRIGGER handle_replaceable_events\n\ AFTER INSERT ON events\n\ WHEN NEW.event_type = 'replaceable'\n\ BEGIN\n\ DELETE FROM events \n\ WHERE pubkey = NEW.pubkey \n\ AND kind = NEW.kind \n\ AND event_type = 'replaceable'\n\ AND id != NEW.id;\n\ END;\n\ \n\ -- Persistent Subscriptions Logging Tables (Phase 2)\n\ -- Optional database logging for subscription analytics and debugging\n\ \n\ -- Subscription events log\n\ CREATE TABLE subscription_events (\n\ id INTEGER PRIMARY KEY AUTOINCREMENT,\n\ subscription_id TEXT NOT NULL, -- Subscription ID from client\n\ client_ip TEXT NOT NULL, -- Client IP address\n\ event_type TEXT NOT NULL CHECK (event_type IN ('created', 'closed', 'expired', 'disconnected')),\n\ filter_json TEXT, -- JSON representation of filters (for created events)\n\ events_sent INTEGER DEFAULT 0, -- Number of events sent to this subscription\n\ created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\ ended_at INTEGER, -- When subscription ended (for closed/expired/disconnected)\n\ duration INTEGER -- Computed: ended_at - created_at\n\ );\n\ \n\ -- Subscription metrics summary\n\ CREATE TABLE subscription_metrics (\n\ id INTEGER PRIMARY KEY AUTOINCREMENT,\n\ date TEXT NOT NULL, -- Date (YYYY-MM-DD)\n\ total_created INTEGER DEFAULT 0, -- Total subscriptions created\n\ total_closed INTEGER DEFAULT 0, -- Total subscriptions closed\n\ total_events_broadcast INTEGER DEFAULT 0, -- Total events broadcast\n\ avg_duration REAL DEFAULT 0, -- Average subscription duration\n\ peak_concurrent INTEGER DEFAULT 0, -- Peak concurrent subscriptions\n\ updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\ UNIQUE(date)\n\ );\n\ \n\ -- Event broadcasting log (optional, for detailed analytics)\n\ CREATE TABLE event_broadcasts (\n\ id INTEGER PRIMARY KEY AUTOINCREMENT,\n\ event_id TEXT NOT NULL, -- Event ID that was broadcast\n\ subscription_id TEXT NOT NULL, -- Subscription that received it\n\ client_ip TEXT NOT NULL, -- Client IP\n\ broadcast_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\ FOREIGN KEY (event_id) REFERENCES events(id)\n\ );\n\ \n\ -- Indexes for subscription logging performance\n\ CREATE INDEX idx_subscription_events_id ON subscription_events(subscription_id);\n\ CREATE INDEX idx_subscription_events_type ON subscription_events(event_type);\n\ CREATE INDEX idx_subscription_events_created ON subscription_events(created_at DESC);\n\ CREATE INDEX idx_subscription_events_client ON subscription_events(client_ip);\n\ \n\ CREATE INDEX idx_subscription_metrics_date ON subscription_metrics(date DESC);\n\ \n\ CREATE INDEX idx_event_broadcasts_event ON event_broadcasts(event_id);\n\ CREATE INDEX idx_event_broadcasts_sub ON event_broadcasts(subscription_id);\n\ CREATE INDEX idx_event_broadcasts_time ON event_broadcasts(broadcast_at DESC);\n\ \n\ -- Trigger to update subscription duration when ended\n\ CREATE TRIGGER update_subscription_duration\n\ AFTER UPDATE OF ended_at ON subscription_events\n\ WHEN NEW.ended_at IS NOT NULL AND OLD.ended_at IS NULL\n\ BEGIN\n\ UPDATE subscription_events\n\ SET duration = NEW.ended_at - NEW.created_at\n\ WHERE id = NEW.id;\n\ END;\n\ \n\ -- View for subscription analytics\n\ CREATE VIEW subscription_analytics AS\n\ SELECT\n\ date(created_at, 'unixepoch') as date,\n\ COUNT(*) as subscriptions_created,\n\ COUNT(CASE WHEN ended_at IS NOT NULL THEN 1 END) as subscriptions_ended,\n\ AVG(CASE WHEN duration IS NOT NULL THEN duration END) as avg_duration_seconds,\n\ MAX(events_sent) as max_events_sent,\n\ AVG(events_sent) as avg_events_sent,\n\ COUNT(DISTINCT client_ip) as unique_clients\n\ FROM subscription_events\n\ GROUP BY date(created_at, 'unixepoch')\n\ ORDER BY date DESC;\n\ \n\ -- View for current active subscriptions (from log perspective)\n\ CREATE VIEW active_subscriptions_log AS\n\ SELECT\n\ subscription_id,\n\ client_ip,\n\ filter_json,\n\ events_sent,\n\ created_at,\n\ (strftime('%s', 'now') - created_at) as duration_seconds\n\ FROM subscription_events\n\ WHERE event_type = 'created'\n\ AND subscription_id NOT IN (\n\ SELECT subscription_id FROM subscription_events\n\ WHERE event_type IN ('closed', 'expired', 'disconnected')\n\ );\n\ \n\ -- ================================\n\ -- CONFIGURATION MANAGEMENT TABLES\n\ -- ================================\n\ \n\ -- Core server configuration table\n\ CREATE TABLE config (\n\ key TEXT PRIMARY KEY, -- Configuration key (unique identifier)\n\ value TEXT NOT NULL, -- Configuration value (stored as string)\n\ description TEXT, -- Human-readable description\n\ config_type TEXT DEFAULT 'user' CHECK (config_type IN ('system', 'user', 'runtime')),\n\ data_type TEXT DEFAULT 'string' CHECK (data_type IN ('string', 'integer', 'boolean', 'json')),\n\ validation_rules TEXT, -- JSON validation rules (optional)\n\ is_sensitive INTEGER DEFAULT 0, -- 1 if value should be masked in logs\n\ requires_restart INTEGER DEFAULT 0, -- 1 if change requires server restart\n\ created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\ updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))\n\ );\n\ \n\ -- Configuration change history table\n\ CREATE TABLE config_history (\n\ id INTEGER PRIMARY KEY AUTOINCREMENT,\n\ config_key TEXT NOT NULL, -- Key that was changed\n\ old_value TEXT, -- Previous value (NULL for new keys)\n\ new_value TEXT NOT NULL, -- New value\n\ changed_by TEXT DEFAULT 'system', -- Who made the change (system/admin/user)\n\ change_reason TEXT, -- Optional reason for change\n\ changed_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\ FOREIGN KEY (config_key) REFERENCES config(key)\n\ );\n\ \n\ -- Configuration validation errors log\n\ CREATE TABLE config_validation_log (\n\ id INTEGER PRIMARY KEY AUTOINCREMENT,\n\ config_key TEXT NOT NULL,\n\ attempted_value TEXT,\n\ validation_error TEXT NOT NULL,\n\ error_source TEXT DEFAULT 'validation', -- validation/parsing/constraint\n\ attempted_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))\n\ );\n\ \n\ -- Cache for file-based configuration events\n\ CREATE TABLE config_file_cache (\n\ file_path TEXT PRIMARY KEY, -- Full path to config file\n\ file_hash TEXT NOT NULL, -- SHA256 hash of file content\n\ event_id TEXT, -- Nostr event ID from file\n\ event_pubkey TEXT, -- Admin pubkey that signed event\n\ loaded_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\ validation_status TEXT CHECK (validation_status IN ('valid', 'invalid', 'unverified')),\n\ validation_error TEXT -- Error details if invalid\n\ );\n\ \n\ -- Performance indexes for configuration tables\n\ CREATE INDEX idx_config_type ON config(config_type);\n\ CREATE INDEX idx_config_updated ON config(updated_at DESC);\n\ CREATE INDEX idx_config_history_key ON config_history(config_key);\n\ CREATE INDEX idx_config_history_time ON config_history(changed_at DESC);\n\ CREATE INDEX idx_config_validation_key ON config_validation_log(config_key);\n\ CREATE INDEX idx_config_validation_time ON config_validation_log(attempted_at DESC);\n\ \n\ -- Trigger to update timestamp on configuration changes\n\ CREATE TRIGGER update_config_timestamp\n\ AFTER UPDATE ON config\n\ BEGIN\n\ UPDATE config SET updated_at = strftime('%s', 'now') WHERE key = NEW.key;\n\ END;\n\ \n\ -- Trigger to log configuration changes to history\n\ CREATE TRIGGER log_config_changes\n\ AFTER UPDATE ON config\n\ WHEN OLD.value != NEW.value\n\ BEGIN\n\ INSERT INTO config_history (config_key, old_value, new_value, changed_by, change_reason)\n\ VALUES (NEW.key, OLD.value, NEW.value, 'system', 'configuration update');\n\ END;\n\ \n\ -- Active Configuration View\n\ CREATE VIEW active_config AS\n\ SELECT\n\ key,\n\ value,\n\ description,\n\ config_type,\n\ data_type,\n\ requires_restart,\n\ updated_at\n\ FROM config\n\ WHERE config_type IN ('system', 'user')\n\ ORDER BY config_type, key;\n\ \n\ -- Runtime Statistics View\n\ CREATE VIEW runtime_stats AS\n\ SELECT\n\ key,\n\ value,\n\ description,\n\ updated_at\n\ FROM config\n\ WHERE config_type = 'runtime'\n\ ORDER BY key;\n\ \n\ -- Configuration Change Summary\n\ CREATE VIEW recent_config_changes AS\n\ SELECT\n\ ch.config_key,\n\ sc.description,\n\ ch.old_value,\n\ ch.new_value,\n\ ch.changed_by,\n\ ch.change_reason,\n\ ch.changed_at\n\ FROM config_history ch\n\ JOIN config sc ON ch.config_key = sc.key\n\ ORDER BY ch.changed_at DESC\n\ LIMIT 50;\n\ \n\ -- Runtime Statistics (initialized by server on startup)\n\ -- These will be populated when configuration system initializes"; #endif /* SQL_SCHEMA_H */