9.5 KiB
9.5 KiB
Database Configuration Schema Design
Overview
This document outlines the database configuration schema additions for the C Nostr Relay startup config file system. The design follows the Ginxsom admin system approach with signed Nostr events and database storage.
Schema Version Update
- Current Version: 2
- Target Version: 3
- Update: Add server configuration management tables
Core Configuration Tables
1. server_config Table
-- Server configuration table - core configuration storage
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 Types:
system: Core system settings (admin keys, security)user: User-configurable settings (relay info, features)runtime: Dynamic runtime values (statistics, cache)
Data Types:
string: Text valuesinteger: Numeric valuesboolean: True/false values (stored as "true"/"false")json: JSON object/array values
2. config_history Table
-- 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)
);
3. config_validation_log Table
-- 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'))
);
4. Configuration File Cache Table
-- 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
);
Indexes and Performance
-- 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);
Triggers
Update Timestamp Trigger
-- 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;
Configuration History Trigger
-- 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;
Default Configuration Values
Core System Settings
INSERT OR IGNORE INTO server_config (key, value, description, config_type, data_type, requires_restart) VALUES
-- Administrative settings
('admin_pubkey', '', 'Authorized admin public key (hex)', 'system', 'string', 1),
('admin_enabled', 'false', 'Enable admin interface', 'system', 'boolean', 1),
-- Server core settings
('relay_port', '8888', 'WebSocket server port', 'user', 'integer', 1),
('database_path', 'db/c_nostr_relay.db', 'SQLite database file path', 'user', 'string', 1),
('max_connections', '100', 'Maximum concurrent connections', 'user', 'integer', 1),
-- NIP-11 Relay Information
('relay_name', 'C Nostr Relay', 'Relay name for NIP-11', 'user', 'string', 0),
('relay_description', 'High-performance C Nostr relay with SQLite storage', 'Relay description', 'user', 'string', 0),
('relay_contact', '', 'Contact information', 'user', 'string', 0),
('relay_pubkey', '', 'Relay public key', 'user', 'string', 0),
('relay_software', 'https://github.com/laantungir/c-relay', 'Software URL', 'user', 'string', 0),
('relay_version', '0.2.0', 'Software version', 'user', 'string', 0),
-- NIP-13 Proof of Work
('pow_enabled', 'true', 'Enable NIP-13 Proof of Work validation', 'user', 'boolean', 0),
('pow_min_difficulty', '0', 'Minimum PoW difficulty required', 'user', 'integer', 0),
('pow_mode', 'basic', 'PoW validation mode (basic/full/strict)', 'user', 'string', 0),
-- NIP-40 Expiration Timestamp
('expiration_enabled', 'true', 'Enable NIP-40 expiration handling', 'user', 'boolean', 0),
('expiration_strict', 'true', 'Reject expired events on submission', 'user', 'boolean', 0),
('expiration_filter', 'true', 'Filter expired events from responses', 'user', 'boolean', 0),
('expiration_grace_period', '300', 'Grace period for clock skew (seconds)', 'user', 'integer', 0),
-- Subscription limits
('max_subscriptions_per_client', '20', 'Max subscriptions per client', 'user', 'integer', 0),
('max_total_subscriptions', '5000', 'Max total concurrent subscriptions', 'user', 'integer', 0),
('subscription_id_max_length', '64', 'Maximum subscription ID length', 'user', 'integer', 0),
-- Event processing limits
('max_event_tags', '100', 'Maximum tags per event', 'user', 'integer', 0),
('max_content_length', '8196', 'Maximum content length', 'user', 'integer', 0),
('max_message_length', '16384', 'Maximum message length', 'user', 'integer', 0),
-- Performance settings
('default_limit', '500', 'Default query limit', 'user', 'integer', 0),
('max_limit', '5000', 'Maximum query limit', 'user', 'integer', 0);
Runtime Statistics
INSERT OR IGNORE INTO server_config (key, value, description, config_type, data_type) VALUES
-- Runtime statistics (updated by server)
('server_start_time', '0', 'Server startup timestamp', 'runtime', 'integer'),
('total_events_processed', '0', 'Total events processed', 'runtime', 'integer'),
('total_subscriptions_created', '0', 'Total subscriptions created', 'runtime', 'integer'),
('current_connections', '0', 'Current active connections', 'runtime', 'integer'),
('database_size_bytes', '0', 'Database file size in bytes', 'runtime', 'integer');
Configuration Views
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;
Validation Rules Format
Configuration validation rules are stored as JSON strings in the validation_rules column:
{
"type": "integer",
"min": 1,
"max": 65535,
"required": true
}
{
"type": "string",
"pattern": "^[0-9a-fA-F]{64}$",
"required": false,
"description": "64-character hex string"
}
{
"type": "boolean",
"required": true
}
Migration Strategy
- Phase 1: Add configuration tables to existing schema
- Phase 2: Populate with current hardcoded values
- Phase 3: Update application code to read from database
- Phase 4: Add file-based configuration loading
- Phase 5: Remove hardcoded defaults and environment variable fallbacks
Integration Points
- Startup: Load configuration from file → database → apply to application
- Runtime: Read configuration values from database cache
- Updates: Write changes to database → optionally update file
- Validation: Validate all configuration changes before applying
- History: Track all configuration changes for audit purposes