Metadata database tracks all uploads with project, package, tag, and timestamp queryable via API

This commit is contained in:
Mondo Diaz
2026-01-07 12:31:44 -06:00
parent 81458b3bcb
commit 2f1891cf01
24 changed files with 5044 additions and 2123 deletions

View File

@@ -0,0 +1,98 @@
-- Migration 004: Project and Package History Tables
-- Adds history tracking tables for project and package metadata changes
-- ============================================
-- Project History Table
-- ============================================
CREATE TABLE IF NOT EXISTS project_history (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
field_name VARCHAR(100) NOT NULL,
old_value TEXT,
new_value TEXT,
changed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
changed_by VARCHAR(255) NOT NULL
);
CREATE INDEX IF NOT EXISTS idx_project_history_project_id ON project_history(project_id);
CREATE INDEX IF NOT EXISTS idx_project_history_changed_at ON project_history(changed_at);
CREATE INDEX IF NOT EXISTS idx_project_history_project_changed_at ON project_history(project_id, changed_at);
-- ============================================
-- Package History Table
-- ============================================
CREATE TABLE IF NOT EXISTS package_history (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
package_id UUID NOT NULL REFERENCES packages(id) ON DELETE CASCADE,
field_name VARCHAR(100) NOT NULL,
old_value TEXT,
new_value TEXT,
changed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
changed_by VARCHAR(255) NOT NULL
);
CREATE INDEX IF NOT EXISTS idx_package_history_package_id ON package_history(package_id);
CREATE INDEX IF NOT EXISTS idx_package_history_changed_at ON package_history(changed_at);
CREATE INDEX IF NOT EXISTS idx_package_history_package_changed_at ON package_history(package_id, changed_at);
-- ============================================
-- Project Update Trigger
-- ============================================
CREATE OR REPLACE FUNCTION log_project_changes()
RETURNS TRIGGER AS $$
BEGIN
-- Log description change
IF OLD.description IS DISTINCT FROM NEW.description THEN
INSERT INTO project_history (project_id, field_name, old_value, new_value, changed_by)
VALUES (NEW.id, 'description', OLD.description, NEW.description, COALESCE(current_setting('app.current_user', true), 'system'));
END IF;
-- Log is_public change
IF OLD.is_public IS DISTINCT FROM NEW.is_public THEN
INSERT INTO project_history (project_id, field_name, old_value, new_value, changed_by)
VALUES (NEW.id, 'is_public', OLD.is_public::text, NEW.is_public::text, COALESCE(current_setting('app.current_user', true), 'system'));
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS project_changes_trigger ON projects;
CREATE TRIGGER project_changes_trigger
AFTER UPDATE ON projects
FOR EACH ROW
EXECUTE FUNCTION log_project_changes();
-- ============================================
-- Package Update Trigger
-- ============================================
CREATE OR REPLACE FUNCTION log_package_changes()
RETURNS TRIGGER AS $$
BEGIN
-- Log description change
IF OLD.description IS DISTINCT FROM NEW.description THEN
INSERT INTO package_history (package_id, field_name, old_value, new_value, changed_by)
VALUES (NEW.id, 'description', OLD.description, NEW.description, COALESCE(current_setting('app.current_user', true), 'system'));
END IF;
-- Log format change
IF OLD.format IS DISTINCT FROM NEW.format THEN
INSERT INTO package_history (package_id, field_name, old_value, new_value, changed_by)
VALUES (NEW.id, 'format', OLD.format, NEW.format, COALESCE(current_setting('app.current_user', true), 'system'));
END IF;
-- Log platform change
IF OLD.platform IS DISTINCT FROM NEW.platform THEN
INSERT INTO package_history (package_id, field_name, old_value, new_value, changed_by)
VALUES (NEW.id, 'platform', OLD.platform, NEW.platform, COALESCE(current_setting('app.current_user', true), 'system'));
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS package_changes_trigger ON packages;
CREATE TRIGGER package_changes_trigger
AFTER UPDATE ON packages
FOR EACH ROW
EXECUTE FUNCTION log_package_changes();

View File

@@ -0,0 +1,83 @@
-- Migration 005: Upload Workflow Enhancements
-- Adds status tracking and error handling for uploads
-- ============================================
-- Add status column to uploads table
-- ============================================
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM information_schema.columns
WHERE table_name = 'uploads' AND column_name = 'status') THEN
ALTER TABLE uploads ADD COLUMN status VARCHAR(20) DEFAULT 'completed' NOT NULL;
END IF;
END $$;
-- ============================================
-- Add error_message column for failed uploads
-- ============================================
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM information_schema.columns
WHERE table_name = 'uploads' AND column_name = 'error_message') THEN
ALTER TABLE uploads ADD COLUMN error_message TEXT;
END IF;
END $$;
-- ============================================
-- Add client_checksum column for verification
-- ============================================
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM information_schema.columns
WHERE table_name = 'uploads' AND column_name = 'client_checksum') THEN
ALTER TABLE uploads ADD COLUMN client_checksum VARCHAR(64);
END IF;
END $$;
-- ============================================
-- Add indexes for upload status queries
-- ============================================
CREATE INDEX IF NOT EXISTS idx_uploads_status ON uploads(status);
CREATE INDEX IF NOT EXISTS idx_uploads_status_uploaded_at ON uploads(status, uploaded_at);
-- ============================================
-- Add constraint to validate status values
-- ============================================
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM information_schema.constraint_column_usage
WHERE constraint_name = 'check_upload_status') THEN
ALTER TABLE uploads ADD CONSTRAINT check_upload_status
CHECK (status IN ('pending', 'completed', 'failed'));
END IF;
END $$;
-- ============================================
-- Create table for tracking in-progress uploads (for 409 conflict detection)
-- ============================================
CREATE TABLE IF NOT EXISTS upload_locks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
sha256_hash VARCHAR(64) NOT NULL,
package_id UUID NOT NULL REFERENCES packages(id) ON DELETE CASCADE,
locked_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
locked_by VARCHAR(255) NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
UNIQUE(sha256_hash, package_id)
);
CREATE INDEX IF NOT EXISTS idx_upload_locks_expires_at ON upload_locks(expires_at);
CREATE INDEX IF NOT EXISTS idx_upload_locks_hash_package ON upload_locks(sha256_hash, package_id);
-- ============================================
-- Function to clean up expired upload locks
-- ============================================
CREATE OR REPLACE FUNCTION cleanup_expired_upload_locks()
RETURNS INTEGER AS $$
DECLARE
deleted_count INTEGER;
BEGIN
DELETE FROM upload_locks WHERE expires_at < NOW();
GET DIAGNOSTICS deleted_count = ROW_COUNT;
RETURN deleted_count;
END;
$$ LANGUAGE plpgsql;