Files
c-relay/db/schema.sql
2025-09-05 19:48:49 -04:00

299 lines
11 KiB
SQL

-- C Nostr Relay Database Schema
-- SQLite schema for storing Nostr events with JSON tags support
-- Schema version tracking
PRAGMA user_version = 3;
-- 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', '3'),
('description', 'Hybrid single-table Nostr relay schema with JSON tags and configuration management'),
('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')
);
-- ================================
-- CONFIGURATION MANAGEMENT TABLES
-- ================================
-- Core server configuration table
CREATE TABLE server_config (
key TEXT PRIMARY KEY, -- Configuration key (unique identifier)
value TEXT NOT NULL, -- Configuration value (stored as string)
description TEXT, -- Human-readable description
config_type TEXT DEFAULT 'user' CHECK (config_type IN ('system', 'user', 'runtime')),
data_type TEXT DEFAULT 'string' CHECK (data_type IN ('string', 'integer', 'boolean', 'json')),
validation_rules TEXT, -- JSON validation rules (optional)
is_sensitive INTEGER DEFAULT 0, -- 1 if value should be masked in logs
requires_restart INTEGER DEFAULT 0, -- 1 if change requires server restart
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
);
-- Configuration change history table
CREATE TABLE config_history (
id INTEGER PRIMARY KEY AUTOINCREMENT,
config_key TEXT NOT NULL, -- Key that was changed
old_value TEXT, -- Previous value (NULL for new keys)
new_value TEXT NOT NULL, -- New value
changed_by TEXT DEFAULT 'system', -- Who made the change (system/admin/user)
change_reason TEXT, -- Optional reason for change
changed_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
FOREIGN KEY (config_key) REFERENCES server_config(key)
);
-- Configuration validation errors log
CREATE TABLE config_validation_log (
id INTEGER PRIMARY KEY AUTOINCREMENT,
config_key TEXT NOT NULL,
attempted_value TEXT,
validation_error TEXT NOT NULL,
error_source TEXT DEFAULT 'validation', -- validation/parsing/constraint
attempted_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
);
-- Cache for file-based configuration events
CREATE TABLE config_file_cache (
file_path TEXT PRIMARY KEY, -- Full path to config file
file_hash TEXT NOT NULL, -- SHA256 hash of file content
event_id TEXT, -- Nostr event ID from file
event_pubkey TEXT, -- Admin pubkey that signed event
loaded_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
validation_status TEXT CHECK (validation_status IN ('valid', 'invalid', 'unverified')),
validation_error TEXT -- Error details if invalid
);
-- Performance indexes for configuration tables
CREATE INDEX idx_server_config_type ON server_config(config_type);
CREATE INDEX idx_server_config_updated ON server_config(updated_at DESC);
CREATE INDEX idx_config_history_key ON config_history(config_key);
CREATE INDEX idx_config_history_time ON config_history(changed_at DESC);
CREATE INDEX idx_config_validation_key ON config_validation_log(config_key);
CREATE INDEX idx_config_validation_time ON config_validation_log(attempted_at DESC);
-- Trigger to update timestamp on configuration changes
CREATE TRIGGER update_config_timestamp
AFTER UPDATE ON server_config
BEGIN
UPDATE server_config SET updated_at = strftime('%s', 'now') WHERE key = NEW.key;
END;
-- Trigger to log configuration changes to history
CREATE TRIGGER log_config_changes
AFTER UPDATE ON server_config
WHEN OLD.value != NEW.value
BEGIN
INSERT INTO config_history (config_key, old_value, new_value, changed_by, change_reason)
VALUES (NEW.key, OLD.value, NEW.value, 'system', 'configuration update');
END;
-- Active Configuration View
CREATE VIEW active_config AS
SELECT
key,
value,
description,
config_type,
data_type,
requires_restart,
updated_at
FROM server_config
WHERE config_type IN ('system', 'user')
ORDER BY config_type, key;
-- Runtime Statistics View
CREATE VIEW runtime_stats AS
SELECT
key,
value,
description,
updated_at
FROM server_config
WHERE config_type = 'runtime'
ORDER BY key;
-- Configuration Change Summary
CREATE VIEW recent_config_changes AS
SELECT
ch.config_key,
sc.description,
ch.old_value,
ch.new_value,
ch.changed_by,
ch.change_reason,
ch.changed_at
FROM config_history ch
JOIN server_config sc ON ch.config_key = sc.key
ORDER BY ch.changed_at DESC
LIMIT 50;
-- Runtime Statistics (initialized by server on startup)
-- These will be populated when configuration system initializes