From 097290f23f97420933fc82cbaf9919cd97e07a1f Mon Sep 17 00:00:00 2001 From: Mondo Diaz Date: Thu, 15 Jan 2026 22:48:00 +0000 Subject: [PATCH] Add auto-migration for package_versions triggers (#56) --- backend/app/database.py | 78 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 78 insertions(+) diff --git a/backend/app/database.py b/backend/app/database.py index 17f7054..1c21541 100644 --- a/backend/app/database.py +++ b/backend/app/database.py @@ -151,6 +151,84 @@ def _run_migrations(): END IF; END $$; """, + # Add package_versions indexes and triggers (007_package_versions.sql) + """ + DO $$ + BEGIN + -- Create indexes for package_versions if table exists + IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'package_versions') THEN + -- Indexes for common queries + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_package_versions_package_id') THEN + CREATE INDEX idx_package_versions_package_id ON package_versions(package_id); + END IF; + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_package_versions_artifact_id') THEN + CREATE INDEX idx_package_versions_artifact_id ON package_versions(artifact_id); + END IF; + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_package_versions_package_version') THEN + CREATE INDEX idx_package_versions_package_version ON package_versions(package_id, version); + END IF; + END IF; + END $$; + """, + # Create ref_count trigger functions for package_versions + """ + CREATE OR REPLACE FUNCTION increment_version_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_version_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 triggers for package_versions ref_count + """ + DO $$ + BEGIN + IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'package_versions') THEN + -- Drop and recreate triggers to ensure they're current + DROP TRIGGER IF EXISTS package_versions_ref_count_insert ON package_versions; + CREATE TRIGGER package_versions_ref_count_insert + AFTER INSERT ON package_versions + FOR EACH ROW + EXECUTE FUNCTION increment_version_ref_count(); + + DROP TRIGGER IF EXISTS package_versions_ref_count_delete ON package_versions; + CREATE TRIGGER package_versions_ref_count_delete + AFTER DELETE ON package_versions + FOR EACH ROW + EXECUTE FUNCTION decrement_version_ref_count(); + END IF; + END $$; + """, + # Migrate existing semver tags to package_versions + """ + DO $$ + BEGIN + IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'package_versions') THEN + -- Migrate tags that look like versions (v1.0.0, 1.2.3, 2.0.0-beta, etc.) + INSERT INTO package_versions (package_id, artifact_id, version, version_source, created_by, created_at) + SELECT + t.package_id, + t.artifact_id, + CASE WHEN t.name LIKE 'v%' THEN substring(t.name from 2) ELSE t.name END, + 'migrated_from_tag', + t.created_by, + t.created_at + FROM tags t + WHERE t.name ~ '^v?[0-9]+\.[0-9]+(\.[0-9]+)?([-.][a-zA-Z0-9]+)?$' + ON CONFLICT (package_id, version) DO NOTHING; + END IF; + END $$; + """, ] with engine.connect() as conn: