- Agent roles integration progress - Various backend and frontend updates - Storybook cache cleanup 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude <noreply@anthropic.com>
117 lines
5.5 KiB
PL/PgSQL
117 lines
5.5 KiB
PL/PgSQL
-- Migration 004: Add Context Feedback Tables for RL Context Curator Integration
|
|
-- Created: 2025-01-30
|
|
-- Description: Adds tables for context feedback, agent permissions, and task outcome tracking
|
|
|
|
-- Add RL Context Curator fields to tasks table
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS completion_time INTEGER;
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS errors_encountered INTEGER DEFAULT 0;
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS follow_up_questions INTEGER DEFAULT 0;
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS success_rate REAL;
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS context_used JSONB;
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS context_relevance_score REAL;
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS feedback_collected BOOLEAN DEFAULT false;
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS task_outcome VARCHAR(50);
|
|
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS outcome_confidence REAL;
|
|
|
|
-- Create context_feedback table
|
|
CREATE TABLE IF NOT EXISTS context_feedback (
|
|
id SERIAL PRIMARY KEY,
|
|
context_id VARCHAR(255) NOT NULL,
|
|
agent_id VARCHAR(255) NOT NULL REFERENCES agents(id),
|
|
task_id UUID REFERENCES tasks(id),
|
|
feedback_type VARCHAR(50) NOT NULL CHECK (feedback_type IN ('upvote', 'downvote', 'forgetfulness', 'task_success', 'task_failure')),
|
|
role VARCHAR(100) NOT NULL,
|
|
confidence REAL NOT NULL CHECK (confidence >= 0.0 AND confidence <= 1.0),
|
|
reason TEXT,
|
|
usage_context VARCHAR(255),
|
|
directory_scope VARCHAR(500),
|
|
task_type VARCHAR(100),
|
|
timestamp TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes for context_feedback table
|
|
CREATE INDEX IF NOT EXISTS idx_context_feedback_context_id ON context_feedback(context_id);
|
|
CREATE INDEX IF NOT EXISTS idx_context_feedback_agent_id ON context_feedback(agent_id);
|
|
CREATE INDEX IF NOT EXISTS idx_context_feedback_timestamp ON context_feedback(timestamp);
|
|
CREATE INDEX IF NOT EXISTS idx_context_feedback_feedback_type ON context_feedback(feedback_type);
|
|
CREATE INDEX IF NOT EXISTS idx_context_feedback_role ON context_feedback(role);
|
|
|
|
-- Create agent_permissions table
|
|
CREATE TABLE IF NOT EXISTS agent_permissions (
|
|
id SERIAL PRIMARY KEY,
|
|
agent_id VARCHAR(255) NOT NULL REFERENCES agents(id),
|
|
role VARCHAR(100) NOT NULL,
|
|
directory_patterns TEXT,
|
|
task_types TEXT,
|
|
context_weight REAL DEFAULT 1.0 CHECK (context_weight >= 0.1 AND context_weight <= 2.0),
|
|
active VARCHAR(10) DEFAULT 'true',
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes for agent_permissions table
|
|
CREATE INDEX IF NOT EXISTS idx_agent_permissions_agent_id ON agent_permissions(agent_id);
|
|
CREATE INDEX IF NOT EXISTS idx_agent_permissions_role ON agent_permissions(role);
|
|
CREATE INDEX IF NOT EXISTS idx_agent_permissions_active ON agent_permissions(active);
|
|
|
|
-- Create promotion_rule_history table
|
|
CREATE TABLE IF NOT EXISTS promotion_rule_history (
|
|
id SERIAL PRIMARY KEY,
|
|
rule_version VARCHAR(50) NOT NULL,
|
|
category VARCHAR(100) NOT NULL,
|
|
role VARCHAR(100) NOT NULL,
|
|
weight_value REAL NOT NULL,
|
|
change_reason TEXT,
|
|
previous_value REAL,
|
|
timestamp TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes for promotion_rule_history table
|
|
CREATE INDEX IF NOT EXISTS idx_promotion_rule_history_timestamp ON promotion_rule_history(timestamp);
|
|
CREATE INDEX IF NOT EXISTS idx_promotion_rule_history_category ON promotion_rule_history(category);
|
|
CREATE INDEX IF NOT EXISTS idx_promotion_rule_history_role ON promotion_rule_history(role);
|
|
|
|
-- Create trigger to update updated_at timestamp for agent_permissions
|
|
CREATE OR REPLACE FUNCTION update_agent_permissions_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER IF NOT EXISTS trigger_agent_permissions_updated_at
|
|
BEFORE UPDATE ON agent_permissions
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_agent_permissions_updated_at();
|
|
|
|
-- Insert default agent permissions for existing agents
|
|
INSERT INTO agent_permissions (agent_id, role, directory_patterns, task_types, context_weight)
|
|
SELECT
|
|
id as agent_id,
|
|
COALESCE(role, 'general') as role,
|
|
'*' as directory_patterns,
|
|
'general_development,coding,documentation' as task_types,
|
|
1.0 as context_weight
|
|
FROM agents
|
|
WHERE id NOT IN (SELECT agent_id FROM agent_permissions)
|
|
ON CONFLICT DO NOTHING;
|
|
|
|
-- Add comments to tables
|
|
COMMENT ON TABLE context_feedback IS 'Stores context feedback from agents for RL Context Curator learning';
|
|
COMMENT ON TABLE agent_permissions IS 'Stores agent role-based permissions for context filtering';
|
|
COMMENT ON TABLE promotion_rule_history IS 'Tracks changes to promotion rule weights over time';
|
|
|
|
-- Add comments to key columns
|
|
COMMENT ON COLUMN context_feedback.context_id IS 'Reference to HCFS context ID';
|
|
COMMENT ON COLUMN context_feedback.feedback_type IS 'Type of feedback: upvote, downvote, forgetfulness, task_success, task_failure';
|
|
COMMENT ON COLUMN context_feedback.confidence IS 'Confidence level in the feedback (0.0 to 1.0)';
|
|
COMMENT ON COLUMN agent_permissions.directory_patterns IS 'Comma-separated list of directory patterns this agent can access';
|
|
COMMENT ON COLUMN agent_permissions.context_weight IS 'Weight for context relevance calculation (0.1 to 2.0)';
|
|
|
|
-- Grant permissions (adjust as needed for your setup)
|
|
-- GRANT SELECT, INSERT, UPDATE ON context_feedback TO hive_user;
|
|
-- GRANT SELECT, INSERT, UPDATE ON agent_permissions TO hive_user;
|
|
-- GRANT SELECT, INSERT ON promotion_rule_history TO hive_user;
|
|
|
|
COMMIT; |