Files
ginxsom/db/schema.sql
2025-08-20 06:20:32 -04:00

238 lines
11 KiB
SQL

-- Ginxsom Blossom Server Database Schema
-- SQLite database for blob metadata and server configuration
-- Enable foreign key constraints
PRAGMA foreign_keys = ON;
-- Main blobs table for storing blob metadata
CREATE TABLE IF NOT EXISTS blobs (
sha256 TEXT PRIMARY KEY NOT NULL, -- SHA-256 hash (64 hex chars)
size INTEGER NOT NULL, -- File size in bytes
type TEXT NOT NULL, -- MIME type
uploaded_at INTEGER NOT NULL, -- Unix timestamp
uploader_pubkey TEXT, -- Nostr public key (optional)
filename TEXT, -- Original filename (optional)
CHECK (length(sha256) = 64), -- Ensure valid SHA-256 hash length
CHECK (size >= 0), -- Ensure non-negative size
CHECK (uploaded_at > 0) -- Ensure valid timestamp
);
-- Server configuration table for key-value settings
CREATE TABLE IF NOT EXISTS server_config (
key TEXT PRIMARY KEY NOT NULL, -- Configuration key
value TEXT NOT NULL, -- Configuration value
description TEXT, -- Human-readable description
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')) -- Last update timestamp
);
-- Indexes for performance optimization
CREATE INDEX IF NOT EXISTS idx_blobs_uploaded_at ON blobs(uploaded_at);
CREATE INDEX IF NOT EXISTS idx_blobs_uploader_pubkey ON blobs(uploader_pubkey);
CREATE INDEX IF NOT EXISTS idx_blobs_type ON blobs(type);
CREATE INDEX IF NOT EXISTS idx_blobs_size ON blobs(size);
-- Insert default server configuration
INSERT OR IGNORE INTO server_config (key, value, description) VALUES
('max_file_size', '104857600', 'Maximum file size in bytes (100MB)'),
('require_auth', 'false', 'Whether authentication is required for uploads'),
('allowed_types', '*', 'Allowed MIME types (* for all)'),
('server_name', 'ginxsom', 'Server name for responses'),
('storage_quota', '10737418240', 'Total storage quota in bytes (10GB)'),
('cleanup_interval', '86400', 'Cleanup interval in seconds (daily)'),
('max_upload_rate', '1048576', 'Max upload rate per client in bytes/sec (1MB/s)');
-- View for storage statistics
CREATE VIEW IF NOT EXISTS storage_stats AS
SELECT
COUNT(*) as total_blobs,
SUM(size) as total_bytes,
AVG(size) as avg_blob_size,
MIN(uploaded_at) as first_upload,
MAX(uploaded_at) as last_upload,
COUNT(DISTINCT uploader_pubkey) as unique_uploaders
FROM blobs;
-- View for recent uploads (last 24 hours)
CREATE VIEW IF NOT EXISTS recent_uploads AS
SELECT
sha256,
size,
type,
uploaded_at,
uploader_pubkey,
filename,
datetime(uploaded_at, 'unixepoch') as uploaded_datetime
FROM blobs
WHERE uploaded_at > (strftime('%s', 'now') - 86400)
ORDER BY uploaded_at DESC;
-- ============================================================================
-- AUTHENTICATION RULES SYSTEM
-- ============================================================================
-- Authentication rules table for flexible access control
CREATE TABLE IF NOT EXISTS auth_rules (
id INTEGER PRIMARY KEY AUTOINCREMENT,
rule_type TEXT NOT NULL, -- 'whitelist', 'blacklist', 'hash_blacklist', 'rate_limit', etc.
rule_target TEXT NOT NULL, -- pubkey, hash, IP, MIME type, etc.
rule_value TEXT, -- JSON for complex rules (optional)
operation TEXT NOT NULL DEFAULT '*', -- 'upload', 'delete', 'list', '*' (all operations)
enabled INTEGER NOT NULL DEFAULT 1, -- 0 = disabled, 1 = enabled
priority INTEGER NOT NULL DEFAULT 100, -- Lower numbers = higher priority (for conflict resolution)
expires_at INTEGER, -- Optional expiration timestamp
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
created_by TEXT, -- Admin pubkey who created this rule (optional)
description TEXT, -- Human-readable rule description
CHECK (enabled IN (0, 1)), -- Boolean constraint
CHECK (priority >= 0), -- Priority must be non-negative
CHECK (expires_at IS NULL OR expires_at > created_at) -- Expiration must be in future
);
-- Rule evaluation cache for performance optimization
CREATE TABLE IF NOT EXISTS auth_cache (
cache_key TEXT PRIMARY KEY, -- SHA-256 hash of request parameters
allowed INTEGER NOT NULL, -- 0 = denied, 1 = allowed
rule_id INTEGER, -- Which rule made the decision (optional)
rule_reason TEXT, -- Human-readable reason for decision
expires_at INTEGER NOT NULL, -- Cache entry expiration
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
CHECK (allowed IN (0, 1)), -- Boolean constraint
FOREIGN KEY (rule_id) REFERENCES auth_rules(id) ON DELETE SET NULL
);
-- Indexes for authentication system performance
CREATE INDEX IF NOT EXISTS idx_auth_rules_type_target ON auth_rules(rule_type, rule_target);
CREATE INDEX IF NOT EXISTS idx_auth_rules_operation ON auth_rules(operation);
CREATE INDEX IF NOT EXISTS idx_auth_rules_enabled ON auth_rules(enabled);
CREATE INDEX IF NOT EXISTS idx_auth_rules_priority ON auth_rules(priority);
CREATE INDEX IF NOT EXISTS idx_auth_rules_expires ON auth_rules(expires_at);
CREATE INDEX IF NOT EXISTS idx_auth_cache_expires ON auth_cache(expires_at);
-- ============================================================================
-- ADMINISTRATIVE SYSTEM
-- ============================================================================
-- Administrators table for nostr-based server administration
CREATE TABLE IF NOT EXISTS administrators (
pubkey TEXT PRIMARY KEY NOT NULL, -- Nostr public key (64 hex chars)
permissions TEXT NOT NULL DEFAULT '[]', -- JSON array of permissions
added_by TEXT, -- Pubkey of admin who added this admin
added_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
expires_at INTEGER, -- Optional expiration timestamp
enabled INTEGER NOT NULL DEFAULT 1, -- 0 = disabled, 1 = enabled
description TEXT, -- Human-readable description
last_seen INTEGER, -- Last administrative action timestamp
CHECK (length(pubkey) = 64), -- Ensure valid pubkey length
CHECK (enabled IN (0, 1)), -- Boolean constraint
CHECK (expires_at IS NULL OR expires_at > added_at), -- Expiration must be in future
FOREIGN KEY (added_by) REFERENCES administrators(pubkey) ON DELETE SET NULL
);
-- Administrative actions audit log
CREATE TABLE IF NOT EXISTS admin_log (
id INTEGER PRIMARY KEY AUTOINCREMENT,
admin_pubkey TEXT NOT NULL, -- Which admin performed the action
command TEXT NOT NULL, -- Administrative command executed
parameters TEXT, -- JSON command parameters
result TEXT, -- Success/failure result and details
timestamp INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
event_id TEXT, -- Reference to nostr event (optional)
target_table TEXT, -- Which table was affected (optional)
target_id TEXT, -- Which record was affected (optional)
ip_address TEXT, -- Client IP address (optional)
user_agent TEXT, -- Client user agent (optional)
FOREIGN KEY (admin_pubkey) REFERENCES administrators(pubkey) ON DELETE CASCADE
);
-- Server identity and administrative configuration
INSERT OR IGNORE INTO server_config (key, value, description) VALUES
('server_pubkey', '', 'Server nostr public key (generated on first run)'),
('server_privkey_file', 'keys/server.key', 'Path to encrypted server private key file'),
('admin_relays', '[]', 'JSON array of relay URLs for administrative events'),
('admin_event_processing', 'true', 'Enable nostr-based administrative event processing'),
('require_admin_auth', 'true', 'Require admin authorization for sensitive operations'),
('auth_rules_enabled', 'true', 'Enable flexible authentication rules system'),
('auth_cache_ttl', '300', 'Authentication cache TTL in seconds (5 minutes)'),
('admin_session_timeout', '3600', 'Administrative session timeout in seconds (1 hour)'),
('max_admin_log_entries', '10000', 'Maximum administrative log entries to retain');
-- Indexes for administrative system performance
CREATE INDEX IF NOT EXISTS idx_administrators_enabled ON administrators(enabled);
CREATE INDEX IF NOT EXISTS idx_administrators_expires ON administrators(expires_at);
CREATE INDEX IF NOT EXISTS idx_admin_log_timestamp ON admin_log(timestamp);
CREATE INDEX IF NOT EXISTS idx_admin_log_admin_pubkey ON admin_log(admin_pubkey);
CREATE INDEX IF NOT EXISTS idx_admin_log_command ON admin_log(command);
-- ============================================================================
-- VIEWS FOR ADMINISTRATIVE QUERIES
-- ============================================================================
-- View for active authentication rules
CREATE VIEW IF NOT EXISTS active_auth_rules AS
SELECT
id,
rule_type,
rule_target,
rule_value,
operation,
priority,
expires_at,
created_at,
created_by,
description,
CASE
WHEN expires_at IS NULL THEN 'never'
WHEN expires_at > strftime('%s', 'now') THEN 'active'
ELSE 'expired'
END as status
FROM auth_rules
WHERE enabled = 1
ORDER BY priority ASC, created_at ASC;
-- View for active administrators
CREATE VIEW IF NOT EXISTS active_administrators AS
SELECT
pubkey,
permissions,
added_by,
added_at,
expires_at,
description,
last_seen,
CASE
WHEN expires_at IS NULL THEN 'never'
WHEN expires_at > strftime('%s', 'now') THEN 'active'
ELSE 'expired'
END as status,
datetime(added_at, 'unixepoch') as added_datetime,
datetime(last_seen, 'unixepoch') as last_seen_datetime
FROM administrators
WHERE enabled = 1;
-- View for recent administrative actions (last 7 days)
CREATE VIEW IF NOT EXISTS recent_admin_actions AS
SELECT
id,
admin_pubkey,
command,
parameters,
result,
timestamp,
event_id,
target_table,
target_id,
datetime(timestamp, 'unixepoch') as action_datetime
FROM admin_log
WHERE timestamp > (strftime('%s', 'now') - 604800) -- 7 days
ORDER BY timestamp DESC;
-- View for authentication statistics
CREATE VIEW IF NOT EXISTS auth_stats AS
SELECT
(SELECT COUNT(*) FROM auth_rules WHERE enabled = 1) as active_rules,
(SELECT COUNT(*) FROM auth_rules WHERE enabled = 1 AND expires_at > strftime('%s', 'now')) as non_expired_rules,
(SELECT COUNT(*) FROM auth_cache WHERE expires_at > strftime('%s', 'now')) as cached_decisions,
(SELECT COUNT(*) FROM administrators WHERE enabled = 1) as active_admins,
(SELECT COUNT(*) FROM admin_log WHERE timestamp > (strftime('%s', 'now') - 86400)) as daily_admin_actions;