Files
WHOOSH/migrations/003_add_repositories_table.up.sql
Claude Code 982b63306a Implement comprehensive repository management system for WHOOSH
- Add database migrations for repositories, webhooks, and sync logs tables
- Implement full CRUD API for repository management
- Add web UI with repository list, add form, and management interface
- Support JSONB handling for topics and metadata
- Handle nullable database columns properly
- Integrate with existing WHOOSH dashboard and navigation
- Enable Gitea repository monitoring for issue tracking and CHORUS integration

🤖 Generated with [Claude Code](https://claude.ai/code)

Co-Authored-By: Claude <noreply@anthropic.com>
2025-09-09 19:46:28 +10:00

127 lines
5.0 KiB
SQL

-- Repository monitoring table for WHOOSH
-- Tracks Gitea repositories for issue monitoring and CHORUS integration
CREATE TABLE repositories (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Repository identification
name VARCHAR(255) NOT NULL, -- e.g., "WHOOSH", "CHORUS"
owner VARCHAR(255) NOT NULL, -- e.g., "tony", "chorus-services"
full_name VARCHAR(255) NOT NULL, -- e.g., "tony/WHOOSH"
-- Repository URLs and access
url TEXT NOT NULL, -- Full Gitea URL, e.g., "https://gitea.chorus.services/tony/WHOOSH"
clone_url TEXT, -- Git clone URL
ssh_url TEXT, -- SSH clone URL
-- Repository configuration
source_type VARCHAR(50) NOT NULL DEFAULT 'gitea', -- 'gitea', 'github', 'gitlab'
source_config JSONB DEFAULT '{}', -- Source-specific configuration (API tokens, etc.)
-- Monitoring settings
monitor_issues BOOLEAN NOT NULL DEFAULT true,
monitor_pull_requests BOOLEAN NOT NULL DEFAULT false,
monitor_releases BOOLEAN NOT NULL DEFAULT false,
-- CHORUS/BZZZ integration settings
enable_chorus_integration BOOLEAN NOT NULL DEFAULT true,
chorus_task_labels JSONB DEFAULT '["bzzz-task", "chorus-task"]', -- Labels that trigger CHORUS tasks
auto_assign_teams BOOLEAN NOT NULL DEFAULT true,
-- Repository metadata
description TEXT,
default_branch VARCHAR(100) DEFAULT 'main',
is_private BOOLEAN DEFAULT false,
language VARCHAR(100),
topics JSONB DEFAULT '[]',
-- Monitoring state
last_sync_at TIMESTAMP WITH TIME ZONE,
last_issue_sync TIMESTAMP WITH TIME ZONE,
sync_status VARCHAR(50) NOT NULL DEFAULT 'pending', -- 'pending', 'active', 'error', 'disabled'
sync_error TEXT,
-- Statistics
open_issues_count INTEGER DEFAULT 0,
closed_issues_count INTEGER DEFAULT 0,
total_tasks_created INTEGER DEFAULT 0,
-- Timestamps
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- Constraints
UNIQUE(full_name, source_type) -- Prevent duplicate repositories
);
-- Repository webhooks for real-time updates
CREATE TABLE repository_webhooks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
repository_id UUID NOT NULL REFERENCES repositories(id) ON DELETE CASCADE,
-- Webhook configuration
webhook_url TEXT NOT NULL, -- The webhook endpoint URL
webhook_secret VARCHAR(255), -- Secret for webhook validation
events JSONB NOT NULL DEFAULT '["issues", "pull_request"]', -- Events to listen for
-- Webhook state
is_active BOOLEAN NOT NULL DEFAULT true,
last_delivery_at TIMESTAMP WITH TIME ZONE,
delivery_count INTEGER DEFAULT 0,
failure_count INTEGER DEFAULT 0,
-- Timestamps
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Repository sync logs for debugging and monitoring
CREATE TABLE repository_sync_logs (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
repository_id UUID NOT NULL REFERENCES repositories(id) ON DELETE CASCADE,
-- Sync operation details
sync_type VARCHAR(50) NOT NULL, -- 'full_sync', 'incremental_sync', 'webhook'
operation VARCHAR(100) NOT NULL, -- 'fetch_issues', 'create_task', 'update_task'
-- Sync results
status VARCHAR(50) NOT NULL, -- 'success', 'error', 'warning'
message TEXT,
error_details JSONB,
-- Metrics
items_processed INTEGER DEFAULT 0,
items_created INTEGER DEFAULT 0,
items_updated INTEGER DEFAULT 0,
duration_ms INTEGER,
-- Context
external_id VARCHAR(255), -- Issue ID, PR ID, etc.
external_url TEXT,
-- Timestamps
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Indexes for performance
CREATE INDEX idx_repositories_source_type ON repositories(source_type);
CREATE INDEX idx_repositories_full_name ON repositories(full_name);
CREATE INDEX idx_repositories_sync_status ON repositories(sync_status);
CREATE INDEX idx_repositories_monitor_issues ON repositories(monitor_issues);
CREATE INDEX idx_repositories_enable_chorus ON repositories(enable_chorus_integration);
CREATE INDEX idx_repositories_last_sync ON repositories(last_sync_at);
CREATE INDEX idx_repository_webhooks_repository_id ON repository_webhooks(repository_id);
CREATE INDEX idx_repository_webhooks_active ON repository_webhooks(is_active);
CREATE INDEX idx_repository_sync_logs_repository_id ON repository_sync_logs(repository_id);
CREATE INDEX idx_repository_sync_logs_created_at ON repository_sync_logs(created_at);
CREATE INDEX idx_repository_sync_logs_status ON repository_sync_logs(status);
CREATE INDEX idx_repository_sync_logs_sync_type ON repository_sync_logs(sync_type);
-- Add repository relationship to tasks table
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS repository_id UUID REFERENCES repositories(id) ON DELETE SET NULL;
CREATE INDEX IF NOT EXISTS idx_tasks_repository_id ON tasks(repository_id);
-- Update tasks table to improve repository tracking
ALTER TABLE tasks ALTER COLUMN repository TYPE TEXT; -- Allow longer repository names