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