Files
orchard/migrations/007_package_versions.sql
Mondo Diaz c7346d7867 Add separate version tracking for artifacts
- Add package_versions table with immutable version records
- Support version detection from explicit param, metadata, or filename
- Add version API endpoints (list, get, delete)
- Update ref resolution to check versions before tags
- Add version column to tags table in frontend UI
- Add Create Tag form for pointing tags at existing artifacts
- Update seed data with version records
- Add 16 integration tests for version functionality
2026-01-15 22:34:03 +00:00

68 lines
2.6 KiB
PL/PgSQL

-- Migration: Add package_versions table for separate version tracking
-- This separates immutable versions from mutable tags
-- Create package_versions table
CREATE TABLE IF NOT EXISTS package_versions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
package_id UUID NOT NULL REFERENCES packages(id) ON DELETE CASCADE,
artifact_id VARCHAR(64) NOT NULL REFERENCES artifacts(id),
version VARCHAR(255) NOT NULL,
version_source VARCHAR(50), -- 'explicit', 'filename', 'metadata', 'migrated_from_tag'
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by VARCHAR(255) NOT NULL,
UNIQUE(package_id, version),
UNIQUE(package_id, artifact_id)
);
-- Indexes for common queries
CREATE INDEX IF NOT EXISTS idx_package_versions_package_id ON package_versions(package_id);
CREATE INDEX IF NOT EXISTS idx_package_versions_artifact_id ON package_versions(artifact_id);
CREATE INDEX IF NOT EXISTS idx_package_versions_package_version ON package_versions(package_id, version);
-- Trigger functions for ref_count management (same pattern as tags)
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
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();
-- Data migration: populate from existing semver-pattern tags
-- This extracts versions from tags that look like version numbers
-- Tags like "v1.0.0", "1.2.3", "2.0.0-beta" will be migrated
-- Tags like "latest", "stable", "dev" will NOT be migrated
INSERT INTO package_versions (package_id, artifact_id, version, version_source, created_by, created_at)
SELECT
t.package_id,
t.artifact_id,
-- Strip leading 'v' if present
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;