Fix comprehensive system issues and implement proper vector database backend selection
- Fix reflection memory spam despite zero active characters in scheduler.py - Add character enable/disable functionality to admin interface - Fix Docker configuration with proper network setup and service dependencies - Resolve admin interface JavaScript errors and login issues - Fix MCP import paths for updated package structure - Add comprehensive character management with audit logging - Implement proper character state management and persistence - Fix database connectivity and initialization issues - Add missing audit service for admin operations - Complete Docker stack integration with all required services 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
189
migrations/001_critical_persistence_tables.sql
Normal file
189
migrations/001_critical_persistence_tables.sql
Normal file
@@ -0,0 +1,189 @@
|
||||
-- Phase 1: Critical Data Loss Prevention Migration
|
||||
-- This migration adds essential tables to prevent data loss on application restart
|
||||
|
||||
-- Character state persistence (CRITICAL)
|
||||
CREATE TABLE IF NOT EXISTS character_state (
|
||||
character_id INTEGER PRIMARY KEY REFERENCES characters(id) ON DELETE CASCADE,
|
||||
mood VARCHAR(50),
|
||||
energy FLOAT DEFAULT 1.0,
|
||||
conversation_count INTEGER DEFAULT 0,
|
||||
recent_interactions JSONB DEFAULT '[]'::jsonb,
|
||||
last_updated TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Enhanced character features (CRITICAL)
|
||||
CREATE TABLE IF NOT EXISTS character_knowledge_areas (
|
||||
id SERIAL PRIMARY KEY,
|
||||
character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
topic VARCHAR(100) NOT NULL,
|
||||
expertise_level FLOAT DEFAULT 0.5 CHECK (expertise_level >= 0 AND expertise_level <= 1),
|
||||
last_updated TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(character_id, topic)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS character_goals (
|
||||
id SERIAL PRIMARY KEY,
|
||||
character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
goal_id VARCHAR(255) UNIQUE NOT NULL,
|
||||
description TEXT NOT NULL,
|
||||
status VARCHAR(20) DEFAULT 'active' CHECK (status IN ('active', 'completed', 'paused', 'abandoned')),
|
||||
progress FLOAT DEFAULT 0.0 CHECK (progress >= 0 AND progress <= 1),
|
||||
target_date DATE,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Character reflections history (CRITICAL)
|
||||
CREATE TABLE IF NOT EXISTS character_reflections (
|
||||
id SERIAL PRIMARY KEY,
|
||||
character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
reflection_content TEXT NOT NULL,
|
||||
trigger_event VARCHAR(100),
|
||||
mood_before VARCHAR(50),
|
||||
mood_after VARCHAR(50),
|
||||
insights_gained TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Trust relationships between characters (CRITICAL)
|
||||
CREATE TABLE IF NOT EXISTS character_trust_levels (
|
||||
id SERIAL PRIMARY KEY,
|
||||
source_character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
target_character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
trust_level FLOAT DEFAULT 0.3 CHECK (trust_level >= 0 AND trust_level <= 1),
|
||||
relationship_type VARCHAR(50) DEFAULT 'acquaintance',
|
||||
shared_experiences INTEGER DEFAULT 0,
|
||||
last_interaction TIMESTAMPTZ,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(source_character_id, target_character_id),
|
||||
CHECK(source_character_id != target_character_id)
|
||||
);
|
||||
|
||||
-- Vector store synchronization (CRITICAL)
|
||||
-- Add vector_store_id to existing memories table if not exists
|
||||
ALTER TABLE memories
|
||||
ADD COLUMN IF NOT EXISTS vector_store_id VARCHAR(255),
|
||||
ADD COLUMN IF NOT EXISTS embedding_model VARCHAR(100),
|
||||
ADD COLUMN IF NOT EXISTS embedding_dimension INTEGER;
|
||||
|
||||
-- Vector embeddings backup table
|
||||
CREATE TABLE IF NOT EXISTS vector_embeddings (
|
||||
id SERIAL PRIMARY KEY,
|
||||
memory_id INTEGER REFERENCES memories(id) ON DELETE CASCADE,
|
||||
vector_id VARCHAR(255) NOT NULL,
|
||||
embedding_data BYTEA,
|
||||
vector_database VARCHAR(50) DEFAULT 'chromadb',
|
||||
collection_name VARCHAR(100),
|
||||
embedding_metadata JSONB DEFAULT '{}'::jsonb,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(memory_id, vector_database)
|
||||
);
|
||||
|
||||
-- Conversation context (CRITICAL)
|
||||
CREATE TABLE IF NOT EXISTS conversation_context (
|
||||
conversation_id INTEGER PRIMARY KEY REFERENCES conversations(id) ON DELETE CASCADE,
|
||||
energy_level FLOAT DEFAULT 1.0 CHECK (energy_level >= 0 AND energy_level <= 1),
|
||||
conversation_type VARCHAR(50) DEFAULT 'general',
|
||||
emotional_state JSONB DEFAULT '{}'::jsonb,
|
||||
speaker_patterns JSONB DEFAULT '{}'::jsonb,
|
||||
topic_drift_score FLOAT DEFAULT 0.0,
|
||||
engagement_level FLOAT DEFAULT 0.5,
|
||||
last_updated TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Message quality tracking (CRITICAL)
|
||||
CREATE TABLE IF NOT EXISTS message_quality_metrics (
|
||||
id SERIAL PRIMARY KEY,
|
||||
message_id INTEGER REFERENCES messages(id) ON DELETE CASCADE,
|
||||
creativity_score FLOAT CHECK (creativity_score >= 0 AND creativity_score <= 1),
|
||||
coherence_score FLOAT CHECK (coherence_score >= 0 AND coherence_score <= 1),
|
||||
sentiment_score FLOAT CHECK (sentiment_score >= -1 AND sentiment_score <= 1),
|
||||
engagement_potential FLOAT CHECK (engagement_potential >= 0 AND engagement_potential <= 1),
|
||||
response_time_ms INTEGER,
|
||||
calculated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Memory sharing events (HIGH PRIORITY)
|
||||
CREATE TABLE IF NOT EXISTS memory_sharing_events (
|
||||
id SERIAL PRIMARY KEY,
|
||||
source_character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
target_character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
memory_id INTEGER REFERENCES memories(id) ON DELETE CASCADE,
|
||||
trust_level_at_sharing FLOAT,
|
||||
sharing_reason VARCHAR(200),
|
||||
acceptance_status VARCHAR(20) DEFAULT 'pending' CHECK (acceptance_status IN ('pending', 'accepted', 'rejected')),
|
||||
shared_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
processed_at TIMESTAMPTZ
|
||||
);
|
||||
|
||||
-- Indexes for performance
|
||||
CREATE INDEX IF NOT EXISTS idx_character_state_character_id ON character_state(character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_character_state_last_updated ON character_state(last_updated);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_character_knowledge_character_id ON character_knowledge_areas(character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_character_knowledge_topic ON character_knowledge_areas(topic);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_character_goals_character_id ON character_goals(character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_character_goals_status ON character_goals(status);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_character_reflections_character_id ON character_reflections(character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_character_reflections_created_at ON character_reflections(created_at);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_trust_levels_source ON character_trust_levels(source_character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_trust_levels_target ON character_trust_levels(target_character_id);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_vector_embeddings_memory_id ON vector_embeddings(memory_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_vector_embeddings_vector_id ON vector_embeddings(vector_id);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_conversation_context_conversation_id ON conversation_context(conversation_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_conversation_context_updated ON conversation_context(last_updated);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_message_quality_message_id ON message_quality_metrics(message_id);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_sharing_source ON memory_sharing_events(source_character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_sharing_target ON memory_sharing_events(target_character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_sharing_shared_at ON memory_sharing_events(shared_at);
|
||||
|
||||
-- Update updated_at timestamps automatically
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Add triggers for updated_at columns
|
||||
DROP TRIGGER IF EXISTS update_character_goals_updated_at ON character_goals;
|
||||
CREATE TRIGGER update_character_goals_updated_at
|
||||
BEFORE UPDATE ON character_goals
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
DROP TRIGGER IF EXISTS update_character_trust_levels_updated_at ON character_trust_levels;
|
||||
CREATE TRIGGER update_character_trust_levels_updated_at
|
||||
BEFORE UPDATE ON character_trust_levels
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
DROP TRIGGER IF EXISTS update_vector_embeddings_updated_at ON vector_embeddings;
|
||||
CREATE TRIGGER update_vector_embeddings_updated_at
|
||||
BEFORE UPDATE ON vector_embeddings
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- Insert default character states for existing characters
|
||||
INSERT INTO character_state (character_id, mood, energy, conversation_count)
|
||||
SELECT id, 'neutral', 1.0, 0
|
||||
FROM characters
|
||||
WHERE id NOT IN (SELECT character_id FROM character_state)
|
||||
ON CONFLICT (character_id) DO NOTHING;
|
||||
|
||||
-- Insert default conversation contexts for existing conversations
|
||||
INSERT INTO conversation_context (conversation_id, energy_level, conversation_type)
|
||||
SELECT id, 1.0, 'general'
|
||||
FROM conversations
|
||||
WHERE id NOT IN (SELECT conversation_id FROM conversation_context)
|
||||
ON CONFLICT (conversation_id) DO NOTHING;
|
||||
165
migrations/002_admin_audit_security.sql
Normal file
165
migrations/002_admin_audit_security.sql
Normal file
@@ -0,0 +1,165 @@
|
||||
-- Phase 2: Admin Audit and Security Migration
|
||||
-- This migration adds admin audit logging and security event tracking
|
||||
|
||||
-- Admin audit trail (HIGH PRIORITY)
|
||||
CREATE TABLE IF NOT EXISTS admin_audit_log (
|
||||
id SERIAL PRIMARY KEY,
|
||||
admin_user VARCHAR(100) NOT NULL,
|
||||
action_type VARCHAR(50) NOT NULL,
|
||||
resource_affected VARCHAR(200),
|
||||
changes_made JSONB DEFAULT '{}'::jsonb,
|
||||
request_ip INET,
|
||||
user_agent TEXT,
|
||||
timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
session_id VARCHAR(255),
|
||||
success BOOLEAN DEFAULT TRUE,
|
||||
error_message TEXT
|
||||
);
|
||||
|
||||
-- Security events (HIGH PRIORITY)
|
||||
CREATE TABLE IF NOT EXISTS security_events (
|
||||
id SERIAL PRIMARY KEY,
|
||||
event_type VARCHAR(50) NOT NULL, -- login_attempt, unauthorized_access, admin_action, etc.
|
||||
severity VARCHAR(20) DEFAULT 'info', -- info, warning, error, critical
|
||||
source_ip INET,
|
||||
user_identifier VARCHAR(100),
|
||||
event_data JSONB DEFAULT '{}'::jsonb,
|
||||
timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
resolved BOOLEAN DEFAULT FALSE,
|
||||
resolution_notes TEXT,
|
||||
resolved_at TIMESTAMPTZ,
|
||||
resolved_by VARCHAR(100)
|
||||
);
|
||||
|
||||
-- Performance tracking (HIGH PRIORITY)
|
||||
CREATE TABLE IF NOT EXISTS performance_metrics (
|
||||
id SERIAL PRIMARY KEY,
|
||||
metric_name VARCHAR(100) NOT NULL,
|
||||
metric_value FLOAT NOT NULL,
|
||||
metric_unit VARCHAR(50),
|
||||
character_id INTEGER REFERENCES characters(id) ON DELETE SET NULL,
|
||||
component VARCHAR(100), -- 'llm_client', 'conversation_engine', 'vector_store', etc.
|
||||
timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
additional_data JSONB DEFAULT '{}'::jsonb
|
||||
);
|
||||
|
||||
-- System configuration management (HIGH PRIORITY)
|
||||
CREATE TABLE IF NOT EXISTS system_configuration (
|
||||
id SERIAL PRIMARY KEY,
|
||||
config_section VARCHAR(100) NOT NULL,
|
||||
config_key VARCHAR(200) NOT NULL,
|
||||
config_value JSONB NOT NULL,
|
||||
description TEXT,
|
||||
created_by VARCHAR(100) NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
is_active BOOLEAN DEFAULT TRUE,
|
||||
is_sensitive BOOLEAN DEFAULT FALSE, -- Mark sensitive configs like tokens
|
||||
version INTEGER DEFAULT 1
|
||||
);
|
||||
|
||||
-- Configuration change history
|
||||
CREATE TABLE IF NOT EXISTS system_configuration_history (
|
||||
id SERIAL PRIMARY KEY,
|
||||
config_id INTEGER REFERENCES system_configuration(id) ON DELETE CASCADE,
|
||||
old_value JSONB,
|
||||
new_value JSONB,
|
||||
changed_by VARCHAR(100) NOT NULL,
|
||||
change_reason TEXT,
|
||||
changed_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- File operations audit (MEDIUM PRIORITY)
|
||||
CREATE TABLE IF NOT EXISTS file_operations_log (
|
||||
id SERIAL PRIMARY KEY,
|
||||
character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE,
|
||||
operation_type VARCHAR(20) NOT NULL, -- 'read', 'write', 'delete', 'create'
|
||||
file_path VARCHAR(500) NOT NULL,
|
||||
file_size BIGINT,
|
||||
success BOOLEAN DEFAULT TRUE,
|
||||
error_message TEXT,
|
||||
timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
mcp_server VARCHAR(100), -- Which MCP server performed the operation
|
||||
request_context JSONB DEFAULT '{}'::jsonb
|
||||
);
|
||||
|
||||
-- Admin session tracking
|
||||
CREATE TABLE IF NOT EXISTS admin_sessions (
|
||||
id SERIAL PRIMARY KEY,
|
||||
session_id VARCHAR(255) UNIQUE NOT NULL,
|
||||
admin_user VARCHAR(100) NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
last_activity TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
expires_at TIMESTAMPTZ NOT NULL,
|
||||
source_ip INET,
|
||||
user_agent TEXT,
|
||||
is_active BOOLEAN DEFAULT TRUE
|
||||
);
|
||||
|
||||
-- Indexes for performance
|
||||
CREATE INDEX IF NOT EXISTS idx_admin_audit_user ON admin_audit_log(admin_user);
|
||||
CREATE INDEX IF NOT EXISTS idx_admin_audit_timestamp ON admin_audit_log(timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_admin_audit_action_type ON admin_audit_log(action_type);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_security_events_type ON security_events(event_type);
|
||||
CREATE INDEX IF NOT EXISTS idx_security_events_severity ON security_events(severity);
|
||||
CREATE INDEX IF NOT EXISTS idx_security_events_timestamp ON security_events(timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_security_events_resolved ON security_events(resolved);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_performance_metrics_name ON performance_metrics(metric_name);
|
||||
CREATE INDEX IF NOT EXISTS idx_performance_metrics_timestamp ON performance_metrics(timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_performance_metrics_component ON performance_metrics(component);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_system_config_section_key ON system_configuration(config_section, config_key);
|
||||
CREATE INDEX IF NOT EXISTS idx_system_config_active ON system_configuration(is_active);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_config_history_config_id ON system_configuration_history(config_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_config_history_changed_at ON system_configuration_history(changed_at);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_file_ops_character_id ON file_operations_log(character_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_file_ops_timestamp ON file_operations_log(timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_file_ops_operation_type ON file_operations_log(operation_type);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_admin_sessions_session_id ON admin_sessions(session_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_admin_sessions_user ON admin_sessions(admin_user);
|
||||
CREATE INDEX IF NOT EXISTS idx_admin_sessions_active ON admin_sessions(is_active);
|
||||
|
||||
-- Add updated_at trigger for system_configuration
|
||||
DROP TRIGGER IF EXISTS update_system_configuration_updated_at ON system_configuration;
|
||||
-- Note: We don't have updated_at on system_configuration, so we'll track changes in history table
|
||||
|
||||
-- Insert some initial configuration items
|
||||
INSERT INTO system_configuration (config_section, config_key, config_value, description, created_by, is_sensitive)
|
||||
VALUES
|
||||
('conversation', 'max_conversation_length', '50', 'Maximum number of messages in a conversation', 'system', FALSE),
|
||||
('conversation', 'quiet_hours_start', '23', 'Hour when conversations should wind down', 'system', FALSE),
|
||||
('conversation', 'quiet_hours_end', '7', 'Hour when conversations can resume', 'system', FALSE),
|
||||
('llm', 'max_tokens', '2000', 'Maximum tokens per LLM request', 'system', FALSE),
|
||||
('llm', 'temperature', '0.8', 'LLM temperature setting', 'system', FALSE),
|
||||
('vector_store', 'embedding_model', 'all-MiniLM-L6-v2', 'Embedding model for vector store', 'system', FALSE),
|
||||
('security', 'session_timeout_hours', '24', 'Admin session timeout in hours', 'system', FALSE)
|
||||
ON CONFLICT DO NOTHING;
|
||||
|
||||
-- Create function to log configuration changes
|
||||
CREATE OR REPLACE FUNCTION log_configuration_change()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
-- Only log if the value actually changed
|
||||
IF OLD.config_value IS DISTINCT FROM NEW.config_value THEN
|
||||
INSERT INTO system_configuration_history (
|
||||
config_id, old_value, new_value, changed_by, change_reason
|
||||
) VALUES (
|
||||
NEW.id, OLD.config_value, NEW.config_value,
|
||||
COALESCE(current_setting('app.current_user', TRUE), 'system'),
|
||||
COALESCE(current_setting('app.change_reason', TRUE), 'Configuration update')
|
||||
);
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Add trigger for configuration changes
|
||||
DROP TRIGGER IF EXISTS system_configuration_change_trigger ON system_configuration;
|
||||
CREATE TRIGGER system_configuration_change_trigger
|
||||
AFTER UPDATE ON system_configuration
|
||||
FOR EACH ROW EXECUTE FUNCTION log_configuration_change();
|
||||
Reference in New Issue
Block a user