-- Migration 002: Schema Enhancements -- Adds new fields, indexes, and triggers for improved functionality -- ============================================ -- Packages: Add format and platform fields -- ============================================ ALTER TABLE packages ADD COLUMN IF NOT EXISTS format VARCHAR(50) DEFAULT 'generic'; ALTER TABLE packages ADD COLUMN IF NOT EXISTS platform VARCHAR(50) DEFAULT 'any'; CREATE INDEX IF NOT EXISTS idx_packages_format ON packages(format); CREATE INDEX IF NOT EXISTS idx_packages_platform ON packages(platform); -- ============================================ -- Artifacts: Add checksum_md5, metadata, and CHECK constraints -- ============================================ ALTER TABLE artifacts ADD COLUMN IF NOT EXISTS checksum_md5 VARCHAR(32); ALTER TABLE artifacts ADD COLUMN IF NOT EXISTS metadata JSONB; -- Add CHECK constraints (will fail if data violates them) DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'artifacts_ref_count_check') THEN ALTER TABLE artifacts ADD CONSTRAINT artifacts_ref_count_check CHECK (ref_count >= 0); END IF; IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'artifacts_size_check') THEN ALTER TABLE artifacts ADD CONSTRAINT artifacts_size_check CHECK (size > 0); END IF; END $$; CREATE INDEX IF NOT EXISTS idx_artifacts_metadata ON artifacts USING GIN (metadata); -- ============================================ -- Tags: Add updated_at and composite index -- ============================================ ALTER TABLE tags ADD COLUMN IF NOT EXISTS updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(); CREATE INDEX IF NOT EXISTS idx_tags_package_created_at ON tags(package_id, created_at DESC); -- ============================================ -- Tag History: Add change_type and index -- ============================================ ALTER TABLE tag_history ADD COLUMN IF NOT EXISTS change_type VARCHAR(20) DEFAULT 'update'; DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'tag_history_change_type_check') THEN ALTER TABLE tag_history ADD CONSTRAINT tag_history_change_type_check CHECK (change_type IN ('create', 'update', 'delete')); END IF; END $$; CREATE INDEX IF NOT EXISTS idx_tag_history_changed_at ON tag_history(changed_at); -- ============================================ -- Uploads: Add new fields and composite indexes -- ============================================ ALTER TABLE uploads ADD COLUMN IF NOT EXISTS tag_name VARCHAR(255); ALTER TABLE uploads ADD COLUMN IF NOT EXISTS user_agent VARCHAR(512); ALTER TABLE uploads ADD COLUMN IF NOT EXISTS duration_ms INTEGER; ALTER TABLE uploads ADD COLUMN IF NOT EXISTS deduplicated BOOLEAN DEFAULT false; ALTER TABLE uploads ADD COLUMN IF NOT EXISTS checksum_verified BOOLEAN DEFAULT true; CREATE INDEX IF NOT EXISTS idx_uploads_package_uploaded_at ON uploads(package_id, uploaded_at DESC); CREATE INDEX IF NOT EXISTS idx_uploads_uploaded_by_at ON uploads(uploaded_by, uploaded_at DESC); -- ============================================ -- Audit Logs: Add composite indexes and GIN index -- ============================================ CREATE INDEX IF NOT EXISTS idx_audit_logs_resource_timestamp ON audit_logs(resource, timestamp DESC); CREATE INDEX IF NOT EXISTS idx_audit_logs_user_timestamp ON audit_logs(user_id, timestamp DESC); CREATE INDEX IF NOT EXISTS idx_audit_logs_details ON audit_logs USING GIN (details); -- ============================================ -- Projects: Add partial index for public projects -- ============================================ CREATE INDEX IF NOT EXISTS idx_projects_public ON projects(name) WHERE is_public = true; -- ============================================ -- Triggers: Update tag_changes trigger for change_type -- ============================================ CREATE OR REPLACE FUNCTION track_tag_changes() RETURNS TRIGGER AS $$ BEGIN IF TG_OP = 'UPDATE' AND OLD.artifact_id != NEW.artifact_id THEN INSERT INTO tag_history (id, tag_id, old_artifact_id, new_artifact_id, change_type, changed_at, changed_by) VALUES (gen_random_uuid(), NEW.id, OLD.artifact_id, NEW.artifact_id, 'update', NOW(), NEW.created_by); END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- ============================================ -- Triggers: Auto-update updated_at timestamps -- ============================================ CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Drop triggers if they exist, then recreate DROP TRIGGER IF EXISTS projects_updated_at_trigger ON projects; CREATE TRIGGER projects_updated_at_trigger BEFORE UPDATE ON projects FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); DROP TRIGGER IF EXISTS packages_updated_at_trigger ON packages; CREATE TRIGGER packages_updated_at_trigger BEFORE UPDATE ON packages FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); DROP TRIGGER IF EXISTS tags_updated_at_trigger ON tags; CREATE TRIGGER tags_updated_at_trigger BEFORE UPDATE ON tags FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ============================================ -- Triggers: Maintain artifact ref_count accuracy -- ============================================ CREATE OR REPLACE FUNCTION increment_artifact_ref_count() RETURNS TRIGGER AS $$ BEGIN UPDATE artifacts SET ref_count = ref_count + 1 WHERE id = NEW.artifact_id; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION decrement_artifact_ref_count() RETURNS TRIGGER AS $$ BEGIN UPDATE artifacts SET ref_count = ref_count - 1 WHERE id = OLD.artifact_id; RETURN OLD; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION update_artifact_ref_count() RETURNS TRIGGER AS $$ BEGIN IF OLD.artifact_id != NEW.artifact_id THEN UPDATE artifacts SET ref_count = ref_count - 1 WHERE id = OLD.artifact_id; UPDATE artifacts SET ref_count = ref_count + 1 WHERE id = NEW.artifact_id; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Note: ref_count triggers on tags table -- These track how many tags reference each artifact DROP TRIGGER IF EXISTS tags_ref_count_insert_trigger ON tags; CREATE TRIGGER tags_ref_count_insert_trigger AFTER INSERT ON tags FOR EACH ROW EXECUTE FUNCTION increment_artifact_ref_count(); DROP TRIGGER IF EXISTS tags_ref_count_delete_trigger ON tags; CREATE TRIGGER tags_ref_count_delete_trigger AFTER DELETE ON tags FOR EACH ROW EXECUTE FUNCTION decrement_artifact_ref_count(); DROP TRIGGER IF EXISTS tags_ref_count_update_trigger ON tags; CREATE TRIGGER tags_ref_count_update_trigger AFTER UPDATE ON tags FOR EACH ROW EXECUTE FUNCTION update_artifact_ref_count();