Files
c-relay/clean_schema.sql
2025-10-04 19:04:12 -04:00

314 lines
14 KiB
SQL

-- C Nostr Relay Database Schema
-- SQLite schema for storing Nostr events with JSON tags support
-- Configuration system using config table
-- Schema version tracking
PRAGMA user_version = 7;
-- 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', '7'),
('description', 'Hybrid Nostr relay schema with event-based and table-based configuration'),
('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;
-- Configuration events view (kind 33334)
CREATE VIEW configuration_events AS
SELECT
id,
pubkey as admin_pubkey,
created_at,
content,
tags,
sig
FROM events
WHERE kind = 33334
ORDER BY created_at DESC;
-- 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;
-- Addressable event handling trigger (for kind 33334 configuration events)
CREATE TRIGGER handle_addressable_events
AFTER INSERT ON events
WHEN NEW.event_type = 'addressable'
BEGIN
-- For kind 33334 (configuration), replace previous config from same admin
DELETE FROM events
WHERE pubkey = NEW.pubkey
AND kind = NEW.kind
AND event_type = 'addressable'
AND id != NEW.id;
END;
-- Relay Private Key Secure Storage
-- Stores the relay's private key separately from public configuration
CREATE TABLE relay_seckey (
private_key_hex TEXT NOT NULL CHECK (length(private_key_hex) = 64),
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
);
-- Authentication Rules Table for NIP-42 and Policy Enforcement
-- Used by request_validator.c for unified validation
CREATE TABLE auth_rules (
id INTEGER PRIMARY KEY AUTOINCREMENT,
rule_type TEXT NOT NULL CHECK (rule_type IN ('whitelist', 'blacklist', 'rate_limit', 'auth_required')),
pattern_type TEXT NOT NULL CHECK (pattern_type IN ('pubkey', 'kind', 'ip', 'global')),
pattern_value TEXT,
action TEXT NOT NULL CHECK (action IN ('allow', 'deny', 'require_auth', 'rate_limit')),
parameters TEXT, -- JSON parameters for rate limiting, etc.
active INTEGER NOT NULL DEFAULT 1,
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
);
-- Indexes for auth_rules performance
CREATE INDEX idx_auth_rules_pattern ON auth_rules(pattern_type, pattern_value);
CREATE INDEX idx_auth_rules_type ON auth_rules(rule_type);
CREATE INDEX idx_auth_rules_active ON auth_rules(active);
-- Configuration Table for Table-Based Config Management
-- Hybrid system supporting both event-based and table-based configuration
CREATE TABLE config (
key TEXT PRIMARY KEY,
value TEXT NOT NULL,
data_type TEXT NOT NULL CHECK (data_type IN ('string', 'integer', 'boolean', 'json')),
description TEXT,
category TEXT DEFAULT 'general',
requires_restart INTEGER DEFAULT 0,
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
);
-- Indexes for config table performance
CREATE INDEX idx_config_category ON config(category);
CREATE INDEX idx_config_restart ON config(requires_restart);
CREATE INDEX idx_config_updated ON config(updated_at DESC);
-- Trigger to update config timestamp on changes
CREATE TRIGGER update_config_timestamp
AFTER UPDATE ON config
FOR EACH ROW
BEGIN
UPDATE config SET updated_at = strftime('%s', 'now') WHERE key = NEW.key;
END;
-- Insert default configuration values
INSERT INTO config (key, value, data_type, description, category, requires_restart) VALUES
('relay_description', 'A C Nostr Relay', 'string', 'Relay description', 'general', 0),
('relay_contact', '', 'string', 'Relay contact information', 'general', 0),
('relay_software', 'https://github.com/laanwj/c-relay', 'string', 'Relay software URL', 'general', 0),
('relay_version', '1.0.0', 'string', 'Relay version', 'general', 0),
('relay_port', '8888', 'integer', 'Relay port number', 'network', 1),
('max_connections', '1000', 'integer', 'Maximum concurrent connections', 'network', 1),
('auth_enabled', 'false', 'boolean', 'Enable NIP-42 authentication', 'auth', 0),
('nip42_auth_required_events', 'false', 'boolean', 'Require auth for event publishing', 'auth', 0),
('nip42_auth_required_subscriptions', 'false', 'boolean', 'Require auth for subscriptions', 'auth', 0),
('nip42_auth_required_kinds', '[]', 'json', 'Event kinds requiring authentication', 'auth', 0),
('nip42_challenge_expiration', '600', 'integer', 'Auth challenge expiration seconds', 'auth', 0),
('pow_min_difficulty', '0', 'integer', 'Minimum proof-of-work difficulty', 'validation', 0),
('pow_mode', 'optional', 'string', 'Proof-of-work mode', 'validation', 0),
('nip40_expiration_enabled', 'true', 'boolean', 'Enable event expiration', 'validation', 0),
('nip40_expiration_strict', 'false', 'boolean', 'Strict expiration mode', 'validation', 0),
('nip40_expiration_filter', 'true', 'boolean', 'Filter expired events in queries', 'validation', 0),
('nip40_expiration_grace_period', '60', 'integer', 'Expiration grace period seconds', 'validation', 0),
('max_subscriptions_per_client', '25', 'integer', 'Maximum subscriptions per client', 'limits', 0),
('max_total_subscriptions', '1000', 'integer', 'Maximum total subscriptions', 'limits', 0),
('max_filters_per_subscription', '10', 'integer', 'Maximum filters per subscription', 'limits', 0),
('max_event_tags', '2000', 'integer', 'Maximum tags per event', 'limits', 0),
('max_content_length', '100000', 'integer', 'Maximum event content length', 'limits', 0),
('max_message_length', '131072', 'integer', 'Maximum WebSocket message length', 'limits', 0),
('default_limit', '100', 'integer', 'Default query limit', 'limits', 0),
('max_limit', '5000', 'integer', 'Maximum query limit', 'limits', 0);
-- 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')
);
-- Database Statistics Views for Admin API
-- Event kinds distribution view
CREATE VIEW event_kinds_view AS
SELECT
kind,
COUNT(*) as count,
ROUND(COUNT(*) * 100.0 / (SELECT COUNT(*) FROM events), 2) as percentage
FROM events
GROUP BY kind
ORDER BY count DESC;
-- Top pubkeys by event count view
CREATE VIEW top_pubkeys_view AS
SELECT
pubkey,
COUNT(*) as event_count,
ROUND(COUNT(*) * 100.0 / (SELECT COUNT(*) FROM events), 2) as percentage
FROM events
GROUP BY pubkey
ORDER BY event_count DESC
LIMIT 10;
-- Time-based statistics view
CREATE VIEW time_stats_view AS
SELECT
'total' as period,
COUNT(*) as total_events,
COUNT(DISTINCT pubkey) as unique_pubkeys,
MIN(created_at) as oldest_event,
MAX(created_at) as newest_event
FROM events
UNION ALL
SELECT
'24h' as period,
COUNT(*) as total_events,
COUNT(DISTINCT pubkey) as unique_pubkeys,
MIN(created_at) as oldest_event,
MAX(created_at) as newest_event
FROM events
WHERE created_at >= (strftime('%s', 'now') - 86400)
UNION ALL
SELECT
'7d' as period,
COUNT(*) as total_events,
COUNT(DISTINCT pubkey) as unique_pubkeys,
MIN(created_at) as oldest_event,
MAX(created_at) as newest_event
FROM events
WHERE created_at >= (strftime('%s', 'now') - 604800)
UNION ALL
SELECT
'30d' as period,
COUNT(*) as total_events,
COUNT(DISTINCT pubkey) as unique_pubkeys,
MIN(created_at) as oldest_event,
MAX(created_at) as newest_event
FROM events
WHERE created_at >= (strftime('%s', 'now') - 2592000);