ForeverSmiYngEcologyKit/手动执行sql合并7个关联字段为一个.sql

79 lines
3.6 KiB
MySQL

MERGE INTO uf_WLHJMK a
USING (
WITH tmp AS (
SELECT id, TO_CHAR(glgc) AS glgc, TO_CHAR(glgcxxsjd) AS glgcxxsjd, TO_CHAR(glgcgc) AS glgcgc, TO_CHAR(glzbgl) AS glzbgl, TO_CHAR(glhtgl) AS glhtgl, TO_CHAR(gltbgl) AS gltbgl, TO_CHAR(glqtgl) AS glqtgl
FROM uf_WLHJMK
),
tmp2 AS (
SELECT id,
NVL2(glgc, '58505_gcxx' || SUBSTR(','||TO_CHAR(glgc)||',', INSTR(','||TO_CHAR(glgc)||',', ',', 1, LEVEL) + 1, INSTR(','||TO_CHAR(glgc)||',', ',', 1, LEVEL + 1) - INSTR(','||TO_CHAR(glgc)||',', ',', 1, LEVEL) - 1),'')
AS wysb
FROM tmp
CONNECT BY LEVEL <= LENGTH(glgc) - LENGTH(REPLACE(glgc, ',', '')) + 1
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcxxsjd, '58505_tree' || SUBSTR(','||TO_CHAR(glgcxxsjd)||',', INSTR(','||TO_CHAR(glgcxxsjd)||',', ',', 1, LEVEL) + 1, INSTR(','||TO_CHAR(glgcxxsjd)||',', ',', 1, LEVEL + 1) - INSTR(','||TO_CHAR(glgcxxsjd)||',', ',', 1, LEVEL) - 1),'')
FROM tmp
CONNECT BY LEVEL <= LENGTH(glgcxxsjd) - LENGTH(REPLACE(glgcxxsjd, ',', '')) + 1
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcxxsjd, '58505_gcgc' || SUBSTR(','||TO_CHAR(glgcgc)||',', INSTR(','||TO_CHAR(glgcgc)||',', ',', 1, LEVEL) + 1, INSTR(','||TO_CHAR(glgcgc)||',', ',', 1, LEVEL + 1) - INSTR(','||TO_CHAR(glgcgc)||',', ',', 1, LEVEL) - 1),'')
FROM tmp
CONNECT BY LEVEL <= LENGTH(glgcgc) - LENGTH(REPLACE(glgcgc, ',', '')) + 1
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcxxsjd, '58505_zb' || SUBSTR(','||TO_CHAR(glzbgl)||',', INSTR(','||TO_CHAR(glzbgl)||',', ',', 1, LEVEL) + 1, INSTR(','||TO_CHAR(glzbgl)||',', ',', 1, LEVEL + 1) - INSTR(','||TO_CHAR(glzbgl)||',', ',', 1, LEVEL) - 1),'')
FROM tmp
CONNECT BY LEVEL <= LENGTH(glzbgl) - LENGTH(REPLACE(glzbgl, ',', '')) + 1
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcxxsjd, '58505_ht' || SUBSTR(','||TO_CHAR(glhtgl)||',', INSTR(','||TO_CHAR(glhtgl)||',', ',', 1, LEVEL) + 1, INSTR(','||TO_CHAR(glhtgl)||',', ',', 1, LEVEL + 1) - INSTR(','||TO_CHAR(glhtgl)||',', ',', 1, LEVEL) - 1),'')
FROM tmp
CONNECT BY LEVEL <= LENGTH(glhtgl) - LENGTH(REPLACE(glhtgl, ',', '')) + 1
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcxxsjd, '58505_tb' || SUBSTR(','||TO_CHAR(gltbgl)||',', INSTR(','||TO_CHAR(gltbgl)||',', ',', 1, LEVEL) + 1, INSTR(','||TO_CHAR(gltbgl)||',', ',', 1, LEVEL + 1) - INSTR(','||TO_CHAR(gltbgl)||',', ',', 1, LEVEL) - 1),'')
FROM tmp
CONNECT BY LEVEL <= LENGTH(gltbgl) - LENGTH(REPLACE(gltbgl, ',', '')) + 1
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcxxsjd, '58505_qt' || SUBSTR(','||TO_CHAR(glqtgl)||',', INSTR(','||TO_CHAR(glqtgl)||',', ',', 1, LEVEL) + 1, INSTR(','||TO_CHAR(glqtgl)||',', ',', 1, LEVEL + 1) - INSTR(','||TO_CHAR(glqtgl)||',', ',', 1, LEVEL) - 1),'')
FROM tmp
CONNECT BY LEVEL <= LENGTH(glqtgl) - LENGTH(REPLACE(glqtgl, ',', '')) + 1
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
),
tmp3 AS (
SELECT id,
LISTAGG(wysb, ',') WITHIN GROUP (ORDER BY wysb) AS wysb
FROM tmp2
WHERE wysb IS NOT NULL
GROUP BY id
)
select * from tmp3
) b
ON (a.id = b.id)
WHEN MATCHED THEN
UPDATE SET a.glgcshb = b.wysb