# WHOOSH Database Schema Design ## Autonomous AI Development Teams Data Architecture MVP Schema Subset (Go migrations) - Start with: `teams`, `team_roles`, `team_assignments`, `agents` (minimal fields), `slurp_submissions` (slim), and `communication_channels` (metadata only). - Postpone: reasoning_chains, votes, performance metrics, analytics/materialized views, and most ENUM-heavy objects. Prefer text + check constraints initially where flexibility is beneficial. - Migrations: manage with Go migration tooling (e.g., golang-migrate). Forward-only by default; keep small, reversible steps. ### Overview This document defines the comprehensive database schema for WHOOSH's transformation into an Autonomous AI Development Teams orchestration platform. The schema supports team formation, agent management, task analysis, consensus tracking, and integration with CHORUS, GITEA, and SLURP systems. ## 🗄️ Database Configuration ```yaml Database: PostgreSQL 15+ Extensions: - uuid-ossp (UUID generation) - pg_trgm (Text similarity) - btree_gin (Multi-column indexing) - pg_stat_statements (Performance monitoring) Connection Pooling: AsyncPG with 50 max connections Backup Strategy: Daily full backup + WAL continuous backup ``` ## 🏗️ Schema Architecture ### Core Domain Tables #### 1. Team Management ```sql -- Teams table - Core team information CREATE TABLE teams ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), team_name VARCHAR(255) NOT NULL, status team_status_enum NOT NULL DEFAULT 'forming', phase team_phase_enum NOT NULL DEFAULT 'planning', -- Task reference task_title VARCHAR(255) NOT NULL, task_description TEXT NOT NULL, task_analysis_id UUID REFERENCES task_analyses(id), -- Repository integration repository_url VARCHAR(512), gitea_issue_id INTEGER, gitea_issue_url VARCHAR(512), -- Communication p2p_channel_id VARCHAR(100), ucxl_address VARCHAR(255), -- Timing estimated_completion_at TIMESTAMP, created_at TIMESTAMP NOT NULL DEFAULT NOW(), started_at TIMESTAMP, completed_at TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT NOW(), -- Configuration max_team_size INTEGER DEFAULT 10, quality_gates JSONB NOT NULL DEFAULT '{}', consensus_threshold consensus_type_enum DEFAULT 'majority', -- Metadata metadata JSONB DEFAULT '{}', CONSTRAINT valid_completion_order CHECK ( (started_at IS NULL OR started_at >= created_at) AND (completed_at IS NULL OR completed_at >= started_at) ) ); -- Team status enumeration CREATE TYPE team_status_enum AS ENUM ( 'forming', -- Team being assembled 'active', -- Team working on task 'paused', -- Team temporarily paused 'review', -- Team in review/consensus phase 'completed', -- Team successfully completed task 'dissolved', -- Team disbanded without completion 'archived' -- Team archived for historical reference ); -- Team phase enumeration CREATE TYPE team_phase_enum AS ENUM ( 'planning', -- Initial planning and design 'implementation', -- Active development 'review', -- Code/design review 'testing', -- Quality assurance 'integration', -- Final assembly and deployment 'consensus', -- Final team consensus 'submission' -- SLURP artifact submission ); -- Consensus threshold enumeration CREATE TYPE consensus_type_enum AS ENUM ( 'simple', -- 50% + 1 'majority', -- 60% 'supermajority', -- 66.67% 'unanimous' -- 100% ); ``` #### 2. Agent Management ```sql -- Agents table - AI agent registry CREATE TABLE agents ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), agent_id VARCHAR(100) UNIQUE NOT NULL, name VARCHAR(255) NOT NULL, -- Network identity node_id VARCHAR(100) UNIQUE, endpoint VARCHAR(512) NOT NULL, -- Classification specialization agent_specialization_enum NOT NULL, tier agent_tier_enum DEFAULT 'standard', -- Hardware configuration hardware_config JSONB NOT NULL DEFAULT '{}', -- AI Models ai_models JSONB NOT NULL DEFAULT '[]', -- Status status agent_status_enum NOT NULL DEFAULT 'offline', health_score DECIMAL(3,2) DEFAULT 0.8, current_load DECIMAL(3,2) DEFAULT 0.0, -- Availability max_concurrent_teams INTEGER DEFAULT 2, timezone VARCHAR(50) DEFAULT 'UTC', -- Performance reputation_score DECIMAL(3,2) DEFAULT 0.8, completed_teams INTEGER DEFAULT 0, success_rate DECIMAL(3,2) DEFAULT 0.8, -- Timestamps registered_at TIMESTAMP NOT NULL DEFAULT NOW(), last_seen TIMESTAMP, last_health_check TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT NOW(), -- Metadata metadata JSONB DEFAULT '{}' ); -- Agent specialization enumeration CREATE TYPE agent_specialization_enum AS ENUM ( 'general_developer', 'backend_developer', 'frontend_developer', 'fullstack_developer', 'security_expert', 'devops_engineer', 'database_engineer', 'qa_engineer', 'architecture_specialist', 'performance_engineer', 'ml_engineer', 'data_scientist', 'technical_writer', 'code_reviewer', 'compliance_specialist', 'research_specialist' ); -- Agent tier enumeration CREATE TYPE agent_tier_enum AS ENUM ( 'junior', 'standard', 'senior', 'expert', 'specialist' ); -- Agent status enumeration CREATE TYPE agent_status_enum AS ENUM ( 'offline', 'idle', 'available', 'busy', 'active', 'maintenance', 'error' ); ``` #### 3. Agent Capabilities ```sql -- Agent capabilities - detailed skill tracking CREATE TABLE agent_capabilities ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), agent_id UUID NOT NULL REFERENCES agents(id) ON DELETE CASCADE, -- Capability definition domain VARCHAR(100) NOT NULL, proficiency DECIMAL(3,2) NOT NULL CHECK (proficiency >= 0.0 AND proficiency <= 1.0), -- Skills within domain skills TEXT[] DEFAULT '{}', certifications TEXT[] DEFAULT '{}', -- Performance metrics experience_score DECIMAL(3,2) DEFAULT 0.5, recent_performance DECIMAL(3,2) DEFAULT 0.8, growth_trend DECIMAL(4,3) DEFAULT 0.0, -- Can be negative -- Evidence and validation evidence_sources JSONB DEFAULT '{}', last_validated TIMESTAMP DEFAULT NOW(), validation_confidence DECIMAL(3,2) DEFAULT 0.8, -- Metadata created_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP NOT NULL DEFAULT NOW(), UNIQUE(agent_id, domain) ); ``` #### 4. Team Roles and Assignments ```sql -- Team roles - Available roles within teams CREATE TABLE team_roles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE, -- Role definition role_name VARCHAR(100) NOT NULL, role_type team_role_type_enum NOT NULL, required BOOLEAN DEFAULT true, -- Requirements required_skills TEXT[] DEFAULT '{}', required_domains TEXT[] DEFAULT '{}', minimum_proficiency DECIMAL(3,2) DEFAULT 0.7, -- Capacity max_agents INTEGER DEFAULT 1, current_agents INTEGER DEFAULT 0, -- Workload estimated_effort_hours INTEGER DEFAULT 0, responsibilities TEXT[] DEFAULT '{}', -- AI Model preferences preferred_models TEXT[] DEFAULT '{}', -- Status status role_status_enum DEFAULT 'open', filled_at TIMESTAMP, -- Metadata created_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP NOT NULL DEFAULT NOW(), UNIQUE(team_id, role_name) ); -- Team role type enumeration CREATE TYPE team_role_type_enum AS ENUM ( 'core', -- Essential team role 'support', -- Supporting team role 'optional', -- Optional enhancement role 'oversight' -- Review and governance role ); -- Role status enumeration CREATE TYPE role_status_enum AS ENUM ( 'open', -- Available for applications 'recruiting', -- Actively seeking candidates 'applied', -- Has applicants pending review 'filled', -- Role filled with agent 'locked', -- Role locked with confirmed agent 'completed' -- Role deliverables completed ); ``` ```sql -- Team assignments - Agent-to-team-role assignments CREATE TABLE team_assignments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE, agent_id UUID NOT NULL REFERENCES agents(id) ON DELETE CASCADE, team_role_id UUID NOT NULL REFERENCES team_roles(id) ON DELETE CASCADE, -- Assignment status status assignment_status_enum NOT NULL DEFAULT 'pending', -- Application details application_reason TEXT, commitment_level commitment_level_enum DEFAULT 'full', proposed_approach TEXT, -- Timing availability_start TIMESTAMP, availability_end TIMESTAMP, estimated_hours_per_day DECIMAL(4,2) DEFAULT 8.0, -- Performance tracking contribution_score DECIMAL(3,2) DEFAULT 0.8, peer_rating DECIMAL(3,2), hours_logged INTEGER DEFAULT 0, -- Approval workflow applied_at TIMESTAMP DEFAULT NOW(), reviewed_at TIMESTAMP, approved_at TIMESTAMP, joined_at TIMESTAMP, completed_at TIMESTAMP, -- References previous_teams UUID[] DEFAULT '{}', reference_ratings JSONB DEFAULT '{}', -- Metadata created_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP NOT NULL DEFAULT NOW(), UNIQUE(team_id, agent_id, team_role_id), CONSTRAINT valid_assignment_flow CHECK ( (reviewed_at IS NULL OR reviewed_at >= applied_at) AND (approved_at IS NULL OR approved_at >= reviewed_at) AND (joined_at IS NULL OR joined_at >= approved_at) AND (completed_at IS NULL OR completed_at >= joined_at) ) ); -- Assignment status enumeration CREATE TYPE assignment_status_enum AS ENUM ( 'pending', -- Application submitted, awaiting review 'reviewing', -- Under review by team members 'approved', -- Approved, waiting for agent confirmation 'active', -- Agent actively working in role 'paused', -- Temporarily paused 'completed', -- Role work completed 'rejected', -- Application rejected 'withdrawn' -- Agent withdrew application ); -- Commitment level enumeration CREATE TYPE commitment_level_enum AS ENUM ( 'full', -- Full-time commitment 'partial', -- Part-time commitment 'consulting', -- Advisory/consultation role 'backup' -- Backup/standby role ); ``` #### 5. Task Analysis ```sql -- Task analyses - LLM-powered task analysis results CREATE TABLE task_analyses ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Input task information task_title VARCHAR(255) NOT NULL, task_description TEXT NOT NULL, task_type task_type_enum NOT NULL, repository_url VARCHAR(512), -- Analysis metadata analyzer_version VARCHAR(20) DEFAULT '1.0.0', analysis_model VARCHAR(100) NOT NULL, analysis_timestamp TIMESTAMP NOT NULL DEFAULT NOW(), confidence_score DECIMAL(3,2) NOT NULL, -- Task classification complexity_score DECIMAL(3,2) NOT NULL, risk_level risk_level_enum NOT NULL, estimated_duration_hours INTEGER NOT NULL, -- Domain analysis primary_domains TEXT[] NOT NULL DEFAULT '{}', secondary_domains TEXT[] DEFAULT '{}', -- Requirements analysis skill_requirements JSONB NOT NULL DEFAULT '{}', quality_requirements JSONB DEFAULT '{}', compliance_requirements TEXT[] DEFAULT '{}', -- Risk assessment risk_factors JSONB DEFAULT '{}', critical_success_factors TEXT[] DEFAULT '{}', -- Team recommendations recommended_team_size INTEGER, recommended_roles JSONB NOT NULL DEFAULT '{}', alternative_approaches JSONB DEFAULT '{}', -- Success criteria success_criteria TEXT[] DEFAULT '{}', quality_gates JSONB DEFAULT '{}', -- Metadata and context context_data JSONB DEFAULT '{}', analysis_reasoning TEXT, -- Status tracking used_for_teams INTEGER DEFAULT 0, feedback_score DECIMAL(3,2), created_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP NOT NULL DEFAULT NOW() ); -- Task type enumeration CREATE TYPE task_type_enum AS ENUM ( 'feature', -- New feature development 'bugfix', -- Bug fixing 'migration', -- System migration 'refactor', -- Code refactoring 'research', -- Research and investigation 'optimization', -- Performance optimization 'security', -- Security enhancement 'documentation', -- Documentation work 'testing', -- Testing and QA 'maintenance', -- System maintenance 'integration' -- System integration ); -- Risk level enumeration CREATE TYPE risk_level_enum AS ENUM ( 'low', 'medium-low', 'medium', 'medium-high', 'high', 'critical' ); ``` #### 6. Communication & Collaboration ```sql -- Communication channels - P2P team channels CREATE TABLE communication_channels ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE, -- Channel identity channel_id VARCHAR(100) UNIQUE NOT NULL, channel_name VARCHAR(255) NOT NULL, description TEXT, -- P2P network information ucxl_address VARCHAR(255) UNIQUE NOT NULL, p2p_network_id VARCHAR(100) NOT NULL, -- Configuration privacy channel_privacy_enum DEFAULT 'team_only', features JSONB DEFAULT '{}', moderation_config JSONB DEFAULT '{}', -- Activity metrics message_count INTEGER DEFAULT 0, active_participants INTEGER DEFAULT 0, last_activity TIMESTAMP, -- Lifecycle created_at TIMESTAMP NOT NULL DEFAULT NOW(), archived_at TIMESTAMP, archive_after_days INTEGER DEFAULT 90, -- Status status channel_status_enum DEFAULT 'active' ); -- Channel privacy enumeration CREATE TYPE channel_privacy_enum AS ENUM ( 'public', -- Visible to all 'team_only', -- Team members only 'private', -- Invitation only 'archived' -- Read-only archived ); -- Channel status enumeration CREATE TYPE channel_status_enum AS ENUM ( 'active', 'paused', 'archived', 'deleted' ); ``` ```sql -- Topic streams - Organized discussion topics within channels CREATE TABLE topic_streams ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), channel_id UUID NOT NULL REFERENCES communication_channels(id) ON DELETE CASCADE, -- Stream identity stream_name VARCHAR(100) NOT NULL, description TEXT, ucxl_address VARCHAR(255) UNIQUE NOT NULL, -- Organization display_order INTEGER DEFAULT 0, color_code VARCHAR(7) DEFAULT '#3b82f6', -- Activity tracking message_count INTEGER DEFAULT 0, subscribers INTEGER DEFAULT 0, last_message_at TIMESTAMP, -- Metadata created_at TIMESTAMP NOT NULL DEFAULT NOW(), archived_at TIMESTAMP, UNIQUE(channel_id, stream_name) ); ``` #### 7. HMMM Reasoning Integration ```sql -- Reasoning chains - HMMM structured reasoning CREATE TABLE reasoning_chains ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Context agent_id UUID NOT NULL REFERENCES agents(id), team_id UUID REFERENCES teams(id), channel_id UUID REFERENCES communication_channels(id), topic_stream_id UUID REFERENCES topic_streams(id), -- Reasoning identity reasoning_id VARCHAR(100) UNIQUE NOT NULL, ucxl_address VARCHAR(255) UNIQUE NOT NULL, -- Content title VARCHAR(255) NOT NULL, context_description TEXT NOT NULL, -- Reasoning structure problem_statement TEXT NOT NULL, options_considered JSONB NOT NULL DEFAULT '[]', analysis TEXT NOT NULL, conclusion TEXT NOT NULL, confidence_score DECIMAL(3,2) NOT NULL, -- Evidence and support supporting_evidence TEXT[] DEFAULT '{}', related_artifacts TEXT[] DEFAULT '{}', references JSONB DEFAULT '{}', -- Team interaction questions_for_team TEXT[] DEFAULT '{}', requesting_feedback BOOLEAN DEFAULT false, decision_required BOOLEAN DEFAULT false, feedback_deadline TIMESTAMP, -- Consensus tracking consensus_reached BOOLEAN DEFAULT false, consensus_type consensus_type_enum, consensus_timestamp TIMESTAMP, -- Activity tracking views INTEGER DEFAULT 0, responses INTEGER DEFAULT 0, agreement_score DECIMAL(3,2), -- SLURP integration slurp_ingested BOOLEAN DEFAULT false, slurp_address VARCHAR(255), -- Timestamps published_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP NOT NULL DEFAULT NOW() ); ``` ```sql -- Reasoning responses - Team feedback on reasoning CREATE TABLE reasoning_responses ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), reasoning_id UUID NOT NULL REFERENCES reasoning_chains(id) ON DELETE CASCADE, agent_id UUID NOT NULL REFERENCES agents(id), -- Response content response_type response_type_enum NOT NULL, response_content TEXT NOT NULL, -- Evaluation agreement_level agreement_level_enum NOT NULL, confidence_in_response DECIMAL(3,2) DEFAULT 0.8, -- Additional context alternative_suggestions TEXT, concerns_raised TEXT, supporting_evidence TEXT[] DEFAULT '{}', -- Interaction builds_on_response UUID REFERENCES reasoning_responses(id), response_thread INTEGER DEFAULT 1, -- Timestamps submitted_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP NOT NULL DEFAULT NOW(), UNIQUE(reasoning_id, agent_id, submitted_at) ); -- Response type enumeration CREATE TYPE response_type_enum AS ENUM ( 'agreement', -- Agrees with reasoning 'disagreement', -- Disagrees with reasoning 'enhancement', -- Suggests improvements 'alternative', -- Proposes alternative 'clarification', -- Asks for clarification 'evidence', -- Provides additional evidence 'concern' -- Raises concerns ); -- Agreement level enumeration CREATE TYPE agreement_level_enum AS ENUM ( 'strong_disagree', 'disagree', 'neutral', 'agree', 'strong_agree' ); ``` #### 8. Consensus & Decision Making ```sql -- Team votes - Democratic decision making CREATE TABLE team_votes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE, -- Vote identity and description vote_title VARCHAR(255) NOT NULL, description TEXT NOT NULL, vote_type vote_type_enum NOT NULL, -- Consensus requirements consensus_threshold consensus_type_enum NOT NULL, minimum_participation INTEGER NOT NULL, -- Voting period voting_starts_at TIMESTAMP NOT NULL DEFAULT NOW(), voting_ends_at TIMESTAMP NOT NULL, duration_hours INTEGER NOT NULL, -- Context and rationale reasoning_references UUID[] DEFAULT '{}', decision_impact impact_level_enum NOT NULL, implementation_dependencies TEXT[] DEFAULT '{}', -- Vote options options JSONB NOT NULL DEFAULT '[]', -- Eligibility eligible_roles TEXT[] DEFAULT '{}', eligible_agents UUID[] DEFAULT '{}', voting_weights JSONB DEFAULT '{}', -- Results status vote_status_enum DEFAULT 'active', total_eligible_voters INTEGER DEFAULT 0, votes_cast INTEGER DEFAULT 0, participation_rate DECIMAL(3,2) DEFAULT 0.0, -- Outcome winning_option VARCHAR(255), consensus_achieved BOOLEAN DEFAULT false, final_tally JSONB DEFAULT '{}', -- Timestamps created_at TIMESTAMP NOT NULL DEFAULT NOW(), closed_at TIMESTAMP, results_calculated_at TIMESTAMP, CONSTRAINT valid_voting_period CHECK (voting_ends_at > voting_starts_at) ); -- Vote type enumeration CREATE TYPE vote_type_enum AS ENUM ( 'single_choice', -- Choose one option 'multiple_choice', -- Choose multiple options 'approval', -- Approve/disapprove 'ranking', -- Rank options in order 'confidence' -- Rate confidence in options ); -- Impact level enumeration CREATE TYPE impact_level_enum AS ENUM ( 'minor', 'moderate', 'significant', 'major', 'critical' ); -- Vote status enumeration CREATE TYPE vote_status_enum AS ENUM ( 'scheduled', -- Vote scheduled for future 'active', -- Vote currently active 'extended', -- Voting period extended 'closed', -- Voting closed, counting votes 'completed', -- Results finalized 'cancelled', -- Vote cancelled 'invalid' -- Vote invalidated ); ``` ```sql -- Vote submissions - Individual agent votes CREATE TABLE vote_submissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), vote_id UUID NOT NULL REFERENCES team_votes(id) ON DELETE CASCADE, agent_id UUID NOT NULL REFERENCES agents(id), -- Vote details selected_options JSONB NOT NULL, vote_weight DECIMAL(3,2) DEFAULT 1.0, confidence_level DECIMAL(3,2), -- Rationale reasoning TEXT, supporting_evidence TEXT[] DEFAULT '{}', -- Vote metadata submission_method submission_method_enum DEFAULT 'direct', ip_address INET, user_agent TEXT, -- Timestamps submitted_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP, UNIQUE(vote_id, agent_id) ); -- Submission method enumeration CREATE TYPE submission_method_enum AS ENUM ( 'direct', -- Direct web interface 'api', -- API submission 'p2p_channel', -- P2P channel integration 'automated' -- Automated system submission ); ``` #### 9. Artifact & SLURP Integration ```sql -- Team artifacts - Deliverables and work products CREATE TABLE team_artifacts ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE, -- Artifact identity title VARCHAR(255) NOT NULL, description TEXT, artifact_type artifact_type_enum NOT NULL, version VARCHAR(20) DEFAULT '1.0.0', -- Content and location content_hash VARCHAR(64), file_paths TEXT[] DEFAULT '{}', repository_refs JSONB DEFAULT '{}', -- Authorship and attribution primary_authors UUID[] DEFAULT '{}', contributing_agents UUID[] DEFAULT '{}', creation_process TEXT, -- Quality metrics quality_score DECIMAL(3,2), test_coverage DECIMAL(3,2), security_score DECIMAL(3,2), peer_review_score DECIMAL(3,2), -- SLURP integration slurp_packaged BOOLEAN DEFAULT false, slurp_address VARCHAR(255), ucxl_address VARCHAR(255), -- Metadata tags TEXT[] DEFAULT '{}', metadata JSONB DEFAULT '{}', -- Lifecycle created_at TIMESTAMP NOT NULL DEFAULT NOW(), updated_at TIMESTAMP NOT NULL DEFAULT NOW(), finalized_at TIMESTAMP ); -- Artifact type enumeration CREATE TYPE artifact_type_enum AS ENUM ( 'code', -- Source code 'documentation', -- Documentation 'test', -- Test cases and data 'configuration', -- Configuration files 'design', -- Design documents 'architecture', -- Architecture diagrams 'decision', -- Decision records 'reasoning', -- Reasoning chains 'package' -- Complete package bundle ); ``` ```sql -- SLURP submissions - Artifact submissions to SLURP CREATE TABLE slurp_submissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE, -- Submission identity submission_type submission_type_enum NOT NULL, slurp_address VARCHAR(255) UNIQUE NOT NULL, ucxl_address VARCHAR(255) UNIQUE NOT NULL, -- Packaging information packaging_job_id VARCHAR(100) UNIQUE, included_artifacts UUID[] NOT NULL DEFAULT '{}', -- Quality verification quality_gates_passed TEXT[] DEFAULT '{}', overall_quality_score DECIMAL(3,2), institutional_score DECIMAL(3,2), -- Team consensus consensus_vote_id UUID REFERENCES team_votes(id), consensus_result consensus_result_enum, team_confidence DECIMAL(3,2), -- Institutional compliance provenance_verified BOOLEAN DEFAULT false, secrets_clean BOOLEAN DEFAULT false, temporal_pin TIMESTAMP, decision_rationale TEXT, -- SLURP response submission_status slurp_status_enum DEFAULT 'preparing', slurp_response JSONB DEFAULT '{}', error_message TEXT, -- Metrics total_files INTEGER DEFAULT 0, code_files INTEGER DEFAULT 0, test_files INTEGER DEFAULT 0, documentation_files INTEGER DEFAULT 0, reasoning_chains INTEGER DEFAULT 0, decisions INTEGER DEFAULT 0, -- Timestamps prepared_at TIMESTAMP NOT NULL DEFAULT NOW(), submitted_at TIMESTAMP, accepted_at TIMESTAMP, indexed_at TIMESTAMP ); -- Submission type enumeration CREATE TYPE submission_type_enum AS ENUM ( 'team_deliverable', -- Complete team deliverable 'milestone', -- Project milestone 'partial_submission', -- Partial work submission 'decision_record', -- Decision documentation 'knowledge_artifact' -- Knowledge base contribution ); -- Consensus result enumeration CREATE TYPE consensus_result_enum AS ENUM ( 'unanimous_approval', 'majority_approval', 'conditional_approval', 'split_decision', 'rejection' ); -- SLURP status enumeration CREATE TYPE slurp_status_enum AS ENUM ( 'preparing', -- Packaging in progress 'ready', -- Ready for submission 'submitting', -- Submission in progress 'accepted', -- Accepted by SLURP 'indexed', -- Fully indexed and searchable 'rejected', -- Rejected by SLURP 'error' -- Submission error ); ``` #### 10. Performance & Analytics ```sql -- Performance metrics - Time-series performance data CREATE TABLE performance_metrics ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Context metric_type metric_type_enum NOT NULL, entity_id UUID NOT NULL, -- Can reference teams, agents, etc. entity_type entity_type_enum NOT NULL, -- Timing timestamp TIMESTAMP NOT NULL DEFAULT NOW(), measurement_period_start TIMESTAMP, measurement_period_end TIMESTAMP, -- Metrics data metrics JSONB NOT NULL DEFAULT '{}', -- Metadata collection_source VARCHAR(100) NOT NULL, collection_version VARCHAR(20) DEFAULT '1.0.0', -- Indexes for time-series queries PRIMARY KEY (entity_id, entity_type, metric_type, timestamp) ); -- Metric type enumeration CREATE TYPE metric_type_enum AS ENUM ( 'performance', -- Performance metrics 'quality', -- Quality metrics 'collaboration', -- Collaboration effectiveness 'productivity', -- Productivity metrics 'health', -- System health 'usage', -- Usage statistics 'cost' -- Cost metrics ); -- Entity type enumeration CREATE TYPE entity_type_enum AS ENUM ( 'agent', 'team', 'system', 'channel', 'task' ); ``` ```sql -- System analytics - Aggregated analytics and insights CREATE TABLE system_analytics ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Analysis scope analysis_type analytics_type_enum NOT NULL, scope_type scope_type_enum NOT NULL, scope_id UUID, -- Optional: specific entity ID -- Time period analysis_period_start TIMESTAMP NOT NULL, analysis_period_end TIMESTAMP NOT NULL, -- Results insights JSONB NOT NULL DEFAULT '{}', recommendations JSONB DEFAULT '{}', trends JSONB DEFAULT '{}', predictions JSONB DEFAULT '{}', -- Quality confidence_score DECIMAL(3,2), data_completeness DECIMAL(3,2), -- Processing generated_at TIMESTAMP NOT NULL DEFAULT NOW(), processing_duration_ms INTEGER, data_points_analyzed INTEGER ); -- Analytics type enumeration CREATE TYPE analytics_type_enum AS ENUM ( 'team_performance', 'agent_effectiveness', 'platform_health', 'usage_patterns', 'quality_trends', 'cost_analysis', 'predictive_analysis' ); -- Scope type enumeration CREATE TYPE scope_type_enum AS ENUM ( 'platform', -- Platform-wide 'agent_network', -- All agents 'team_ecosystem', -- All teams 'individual_agent',-- Single agent 'individual_team', -- Single team 'domain_specific' -- Specific domain/skill area ); ``` ## 🔍 Indexes and Performance Optimization ### Primary Indexes ```sql -- Team management indexes CREATE INDEX idx_teams_status ON teams(status) WHERE status IN ('forming', 'active'); CREATE INDEX idx_teams_created_at ON teams(created_at DESC); CREATE INDEX idx_teams_completion ON teams(estimated_completion_at) WHERE completed_at IS NULL; CREATE INDEX idx_teams_gitea ON teams(gitea_issue_id) WHERE gitea_issue_id IS NOT NULL; -- Agent performance indexes CREATE INDEX idx_agents_status ON agents(status) WHERE status IN ('available', 'idle', 'active'); CREATE INDEX idx_agents_specialization ON agents(specialization, tier); CREATE INDEX idx_agents_reputation ON agents(reputation_score DESC, success_rate DESC); CREATE INDEX idx_agents_last_seen ON agents(last_seen DESC) WHERE status != 'offline'; -- Team assignments indexes CREATE INDEX idx_assignments_team_status ON team_assignments(team_id, status); CREATE INDEX idx_assignments_agent_active ON team_assignments(agent_id) WHERE status IN ('active', 'approved'); CREATE INDEX idx_assignments_application_queue ON team_assignments(status, applied_at) WHERE status = 'pending'; -- Capability matching indexes CREATE INDEX idx_capabilities_domain_proficiency ON agent_capabilities(domain, proficiency DESC); CREATE INDEX idx_capabilities_skills_gin ON agent_capabilities USING GIN(skills); CREATE INDEX idx_capabilities_agent_domain ON agent_capabilities(agent_id, domain); -- Communication indexes CREATE INDEX idx_channels_team ON communication_channels(team_id, status); CREATE INDEX idx_channels_activity ON communication_channels(last_activity DESC) WHERE status = 'active'; CREATE INDEX idx_reasoning_team_timestamp ON reasoning_chains(team_id, published_at DESC); CREATE INDEX idx_reasoning_feedback ON reasoning_chains(requesting_feedback, feedback_deadline) WHERE requesting_feedback = true; -- Voting and consensus indexes CREATE INDEX idx_votes_active ON team_votes(team_id, status, voting_ends_at) WHERE status = 'active'; CREATE INDEX idx_vote_submissions_agent ON vote_submissions(agent_id, submitted_at DESC); -- Performance metrics indexes (time-series optimized) CREATE INDEX idx_metrics_entity_time ON performance_metrics(entity_id, entity_type, timestamp DESC); CREATE INDEX idx_metrics_type_time ON performance_metrics(metric_type, timestamp DESC); CREATE INDEX idx_metrics_recent ON performance_metrics(timestamp DESC) WHERE timestamp > NOW() - INTERVAL '7 days'; -- Analytics indexes CREATE INDEX idx_analytics_type_period ON system_analytics(analysis_type, analysis_period_end DESC); CREATE INDEX idx_analytics_scope ON system_analytics(scope_type, scope_id, generated_at DESC); ``` ### Composite Indexes for Complex Queries ```sql -- Team formation optimization CREATE INDEX idx_team_formation_optimization ON team_roles(team_id, status, required) WHERE status IN ('open', 'recruiting'); -- Agent availability optimization CREATE INDEX idx_agent_availability ON agents(status, specialization, current_load, max_concurrent_teams) WHERE status IN ('available', 'idle') AND current_load < 1.0; -- Skill matching optimization CREATE INDEX idx_skill_matching ON agent_capabilities(domain, proficiency, agent_id) WHERE proficiency >= 0.7; -- Communication activity optimization CREATE INDEX idx_communication_activity ON reasoning_chains(team_id, published_at, requesting_feedback, decision_required); ``` ## 🏃‍♂️ Performance Tuning ### Connection Pooling ```python # AsyncPG connection pool configuration POOL_CONFIG = { 'min_size': 10, 'max_size': 50, 'max_queries': 50000, 'max_inactive_connection_lifetime': 300.0, 'command_timeout': 60.0 } ``` ### Query Optimization ```sql -- Materialized views for frequently accessed analytics CREATE MATERIALIZED VIEW team_performance_summary AS SELECT t.id, t.team_name, t.status, COUNT(ta.id) as team_size, AVG(a.reputation_score) as avg_agent_reputation, COUNT(rc.id) as reasoning_chains_count, COUNT(tv.id) as votes_conducted, EXTRACT(EPOCH FROM (COALESCE(t.completed_at, NOW()) - t.created_at))/3600 as duration_hours FROM teams t LEFT JOIN team_assignments ta ON t.id = ta.team_id AND ta.status = 'active' LEFT JOIN agents a ON ta.agent_id = a.id LEFT JOIN reasoning_chains rc ON t.id = rc.team_id LEFT JOIN team_votes tv ON t.id = tv.team_id GROUP BY t.id, t.team_name, t.status, t.created_at, t.completed_at; -- Refresh schedule for materialized view CREATE OR REPLACE FUNCTION refresh_team_performance_summary() RETURNS void AS $$ BEGIN REFRESH MATERIALIZED VIEW CONCURRENTLY team_performance_summary; END; $$ LANGUAGE plpgsql; -- Agent capability summary materialized view CREATE MATERIALIZED VIEW agent_capability_summary AS SELECT a.id, a.agent_id, a.name, a.specialization, a.status, COUNT(ac.id) as capability_count, AVG(ac.proficiency) as avg_proficiency, ARRAY_AGG(DISTINCT ac.domain) as domains, a.reputation_score, a.completed_teams, a.success_rate FROM agents a LEFT JOIN agent_capabilities ac ON a.id = ac.agent_id GROUP BY a.id, a.agent_id, a.name, a.specialization, a.status, a.reputation_score, a.completed_teams, a.success_rate; ``` ## 🔒 Security Considerations ### Row-Level Security ```sql -- Enable RLS on sensitive tables ALTER TABLE teams ENABLE ROW LEVEL SECURITY; ALTER TABLE agents ENABLE ROW LEVEL SECURITY; ALTER TABLE team_assignments ENABLE ROW LEVEL SECURITY; -- Policies for team data access CREATE POLICY team_access_policy ON teams FOR ALL TO whoosh_api_role USING ( -- Team members can access their team data EXISTS ( SELECT 1 FROM team_assignments ta WHERE ta.team_id = teams.id AND ta.agent_id = current_setting('app.current_agent_id')::uuid AND ta.status = 'active' ) OR -- System administrators can access all teams current_setting('app.user_role') = 'admin' ); -- Policies for agent data access CREATE POLICY agent_access_policy ON agents FOR ALL TO whoosh_api_role USING ( -- Agents can access their own data agent_id = current_setting('app.current_agent_id') OR -- Agents can see basic info of teammates EXISTS ( SELECT 1 FROM team_assignments ta1, team_assignments ta2 WHERE ta1.agent_id = agents.id AND ta2.agent_id = current_setting('app.current_agent_id')::uuid AND ta1.team_id = ta2.team_id AND ta1.status = 'active' AND ta2.status = 'active' ) OR -- System can access all agent data current_setting('app.user_role') = 'system' ); ``` ### Data Encryption ```sql -- Sensitive data encryption for PII and secrets CREATE EXTENSION IF NOT EXISTS pgcrypto; -- Function to encrypt sensitive agent metadata CREATE OR REPLACE FUNCTION encrypt_agent_metadata(metadata JSONB) RETURNS JSONB AS $$ BEGIN -- Encrypt any PII fields in metadata IF metadata ? 'contact_info' THEN metadata := jsonb_set( metadata, '{contact_info}', to_jsonb(crypt(metadata->>'contact_info', gen_salt('bf'))) ); END IF; RETURN metadata; END; $$ LANGUAGE plpgsql; ``` ## 📊 Monitoring and Observability ### Performance Monitoring ```sql -- Performance monitoring views CREATE VIEW agent_performance_health AS SELECT a.agent_id, a.name, a.status, a.health_score, a.current_load, COUNT(ta.id) as active_teams, AVG(pm.metrics->>'response_time_ms') as avg_response_time, AVG(pm.metrics->>'tokens_per_second') as avg_tps FROM agents a LEFT JOIN team_assignments ta ON a.id = ta.agent_id AND ta.status = 'active' LEFT JOIN performance_metrics pm ON a.id = pm.entity_id AND pm.entity_type = 'agent' AND pm.timestamp > NOW() - INTERVAL '1 hour' GROUP BY a.id, a.agent_id, a.name, a.status, a.health_score, a.current_load; -- Team formation efficiency view CREATE VIEW team_formation_efficiency AS SELECT DATE(t.created_at) as formation_date, COUNT(*) as teams_formed, AVG(EXTRACT(EPOCH FROM (tr.filled_at - t.created_at))/60) as avg_formation_time_minutes, SUM(CASE WHEN t.status = 'completed' THEN 1 ELSE 0 END) as completed_teams, SUM(CASE WHEN t.status = 'dissolved' THEN 1 ELSE 0 END) as dissolved_teams FROM teams t LEFT JOIN team_roles tr ON t.id = tr.team_id AND tr.required = true WHERE t.created_at > NOW() - INTERVAL '30 days' GROUP BY DATE(t.created_at) ORDER BY formation_date DESC; ``` This comprehensive database schema provides the foundation for WHOOSH's transformation into an Autonomous AI Development Teams platform, supporting sophisticated team orchestration, agent coordination, and collaborative development processes while maintaining performance, security, and scalability.