-- C Nostr Relay Database Schema -- SQLite schema for storing Nostr events with JSON tags support -- Schema version tracking PRAGMA user_version = 2; -- Enable foreign key support PRAGMA foreign_keys = ON; -- Optimize for performance PRAGMA journal_mode = WAL; PRAGMA synchronous = NORMAL; PRAGMA cache_size = 10000; -- Core events table with hybrid single-table design CREATE TABLE events ( id TEXT PRIMARY KEY, -- Nostr event ID (hex string) pubkey TEXT NOT NULL, -- Public key of event author (hex string) created_at INTEGER NOT NULL, -- Event creation timestamp (Unix timestamp) kind INTEGER NOT NULL, -- Event kind (0-65535) event_type TEXT NOT NULL CHECK (event_type IN ('regular', 'replaceable', 'ephemeral', 'addressable')), content TEXT NOT NULL, -- Event content (text content only) sig TEXT NOT NULL, -- Event signature (hex string) tags JSON NOT NULL DEFAULT '[]', -- Event tags as JSON array first_seen INTEGER NOT NULL DEFAULT (strftime('%s', 'now')) -- When relay received event ); -- Core performance indexes CREATE INDEX idx_events_pubkey ON events(pubkey); CREATE INDEX idx_events_kind ON events(kind); CREATE INDEX idx_events_created_at ON events(created_at DESC); CREATE INDEX idx_events_event_type ON events(event_type); -- Composite indexes for common query patterns CREATE INDEX idx_events_kind_created_at ON events(kind, created_at DESC); CREATE INDEX idx_events_pubkey_created_at ON events(pubkey, created_at DESC); CREATE INDEX idx_events_pubkey_kind ON events(pubkey, kind); -- Schema information table CREATE TABLE schema_info ( key TEXT PRIMARY KEY, value TEXT NOT NULL, updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')) ); -- Insert schema metadata INSERT INTO schema_info (key, value) VALUES ('version', '2'), ('description', 'Hybrid single-table Nostr relay schema with JSON tags'), ('created_at', strftime('%s', 'now')); -- Helper views for common queries CREATE VIEW recent_events AS SELECT id, pubkey, created_at, kind, event_type, content FROM events WHERE event_type != 'ephemeral' ORDER BY created_at DESC LIMIT 1000; CREATE VIEW event_stats AS SELECT event_type, COUNT(*) as count, AVG(length(content)) as avg_content_length, MIN(created_at) as earliest, MAX(created_at) as latest FROM events GROUP BY event_type; -- Optimization: Trigger for automatic cleanup of ephemeral events older than 1 hour CREATE TRIGGER cleanup_ephemeral_events AFTER INSERT ON events WHEN NEW.event_type = 'ephemeral' BEGIN DELETE FROM events WHERE event_type = 'ephemeral' AND first_seen < (strftime('%s', 'now') - 3600); END; -- Replaceable event handling trigger CREATE TRIGGER handle_replaceable_events AFTER INSERT ON events WHEN NEW.event_type = 'replaceable' BEGIN DELETE FROM events WHERE pubkey = NEW.pubkey AND kind = NEW.kind AND event_type = 'replaceable' AND id != NEW.id; END; -- Persistent Subscriptions Logging Tables (Phase 2) -- Optional database logging for subscription analytics and debugging -- Subscription events log CREATE TABLE subscription_events ( id INTEGER PRIMARY KEY AUTOINCREMENT, subscription_id TEXT NOT NULL, -- Subscription ID from client client_ip TEXT NOT NULL, -- Client IP address event_type TEXT NOT NULL CHECK (event_type IN ('created', 'closed', 'expired', 'disconnected')), filter_json TEXT, -- JSON representation of filters (for created events) events_sent INTEGER DEFAULT 0, -- Number of events sent to this subscription created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')), ended_at INTEGER, -- When subscription ended (for closed/expired/disconnected) duration INTEGER -- Computed: ended_at - created_at ); -- Subscription metrics summary CREATE TABLE subscription_metrics ( id INTEGER PRIMARY KEY AUTOINCREMENT, date TEXT NOT NULL, -- Date (YYYY-MM-DD) total_created INTEGER DEFAULT 0, -- Total subscriptions created total_closed INTEGER DEFAULT 0, -- Total subscriptions closed total_events_broadcast INTEGER DEFAULT 0, -- Total events broadcast avg_duration REAL DEFAULT 0, -- Average subscription duration peak_concurrent INTEGER DEFAULT 0, -- Peak concurrent subscriptions updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')), UNIQUE(date) ); -- Event broadcasting log (optional, for detailed analytics) CREATE TABLE event_broadcasts ( id INTEGER PRIMARY KEY AUTOINCREMENT, event_id TEXT NOT NULL, -- Event ID that was broadcast subscription_id TEXT NOT NULL, -- Subscription that received it client_ip TEXT NOT NULL, -- Client IP broadcast_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')), FOREIGN KEY (event_id) REFERENCES events(id) ); -- Indexes for subscription logging performance CREATE INDEX idx_subscription_events_id ON subscription_events(subscription_id); CREATE INDEX idx_subscription_events_type ON subscription_events(event_type); CREATE INDEX idx_subscription_events_created ON subscription_events(created_at DESC); CREATE INDEX idx_subscription_events_client ON subscription_events(client_ip); CREATE INDEX idx_subscription_metrics_date ON subscription_metrics(date DESC); CREATE INDEX idx_event_broadcasts_event ON event_broadcasts(event_id); CREATE INDEX idx_event_broadcasts_sub ON event_broadcasts(subscription_id); CREATE INDEX idx_event_broadcasts_time ON event_broadcasts(broadcast_at DESC); -- Trigger to update subscription duration when ended CREATE TRIGGER update_subscription_duration AFTER UPDATE OF ended_at ON subscription_events WHEN NEW.ended_at IS NOT NULL AND OLD.ended_at IS NULL BEGIN UPDATE subscription_events SET duration = NEW.ended_at - NEW.created_at WHERE id = NEW.id; END; -- View for subscription analytics CREATE VIEW subscription_analytics AS SELECT date(created_at, 'unixepoch') as date, COUNT(*) as subscriptions_created, COUNT(CASE WHEN ended_at IS NOT NULL THEN 1 END) as subscriptions_ended, AVG(CASE WHEN duration IS NOT NULL THEN duration END) as avg_duration_seconds, MAX(events_sent) as max_events_sent, AVG(events_sent) as avg_events_sent, COUNT(DISTINCT client_ip) as unique_clients FROM subscription_events GROUP BY date(created_at, 'unixepoch') ORDER BY date DESC; -- View for current active subscriptions (from log perspective) CREATE VIEW active_subscriptions_log AS SELECT subscription_id, client_ip, filter_json, events_sent, created_at, (strftime('%s', 'now') - created_at) as duration_seconds FROM subscription_events WHERE event_type = 'created' AND subscription_id NOT IN ( SELECT subscription_id FROM subscription_events WHERE event_type IN ('closed', 'expired', 'disconnected') );