By using db<>fiddle, you agree to license everything you submit by Creative Commons CC0.
DROP temporary TABLE IF exists t;
create TEMPORARY table t(icd text, diagnose text );
insert into t VALUES
('A00 1','diagnoseA00 1'), ('B34 2;A00 9;A39 5','diagnoseB34 2;diagnoseA00 9;diagnoseA39 5');
Records: 2 Duplicates: 0 Warnings: 0
SELECT * FROM t;
icd | diagnose |
---|---|
A00 1 | diagnoseA00 1 |
B34 2;A00 9;A39 5 | diagnoseB34 2;diagnoseA00 9;diagnoseA39 5 |
DROP temporary TABLE IF exists t_target;
create TEMPORARY table t_target(icd text, diagnose text );
INSERT INTO t_target
(SELECT SUBSTRING_INDEX(SUBSTRING_INDEX(t.diagnose, ';', n.n), ';', -1) value1,
SUBSTRING_INDEX(SUBSTRING_INDEX(t.icd, ';', n.n), ';', -1) value2
FROM t t CROSS JOIN
(
SELECT a.N + b.N * 10 + 1 n
FROM
(SELECT 0 AS N UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9) a
,(SELECT 0 AS N UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9) b
ORDER BY n
) n
WHERE n.n <= 1 + (LENGTH(t.diagnose) - LENGTH(REPLACE(t.diagnose, ';', ''))));
Records: 4 Duplicates: 0 Warnings: 0
SELECT * from t_target;
icd | diagnose |
---|---|
diagnoseA00 1 | A00 1 |
diagnoseB34 2 | B34 2 |
diagnoseA00 9 | A00 9 |
diagnoseA39 5 | A39 5 |