buster/packages/database/drizzle/0101_superb_norman_osborn.sql

38 lines
1.2 KiB
SQL

-- Custom SQL migration file, put your code below! --
-- Populate metric_files_to_report_files table from existing report content
-- Extract metric IDs from report content and create relationships
-- Use CTE to extract all metric IDs from report content first
WITH extracted_metrics AS (
SELECT DISTINCT
rf.id AS report_file_id,
rf.created_by,
(regexp_matches(rf.content, '<metric[^>]*metricId="([a-f0-9]{8}-[a-f0-9]{4}-[a-f0-9]{4}-[a-f0-9]{4}-[a-f0-9]{12})"[^>]*>', 'g'))[1]::UUID AS metric_file_id
FROM report_files rf
WHERE rf.deleted_at IS NULL
AND rf.content ~ '<metric[^>]*metricId="[a-f0-9]{8}-[a-f0-9]{4}-[a-f0-9]{4}-[a-f0-9]{4}-[a-f0-9]{12}"[^>]*>'
)
INSERT INTO metric_files_to_report_files (
metric_file_id,
report_file_id,
created_at,
updated_at,
deleted_at,
created_by
)
SELECT
em.metric_file_id,
em.report_file_id,
CURRENT_TIMESTAMP AS created_at,
CURRENT_TIMESTAMP AS updated_at,
NULL AS deleted_at,
em.created_by
FROM extracted_metrics em
WHERE EXISTS (
SELECT 1
FROM metric_files mf
WHERE mf.id = em.metric_file_id
AND mf.deleted_at IS NULL
)
ON CONFLICT (metric_file_id, report_file_id) DO NOTHING;