-- 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;