'手动执行sql合并7个关联字段为一个'

This commit is contained in:
wintsa 2024-08-22 15:46:36 +08:00
parent ef55bca2e0
commit 75b4c681dc

View File

@ -0,0 +1,71 @@
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' || REGEXP_SUBSTR(glgc, '[^,]+', 1, LEVEL), '') AS wysb
FROM tmp
CONNECT BY REGEXP_SUBSTR(glgc, '[^,]+', 1, LEVEL) IS NOT NULL
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcxxsjd, '58505_tree' || REGEXP_SUBSTR(glgcxxsjd, '[^,]+', 1, LEVEL), '') AS wysb
FROM tmp
CONNECT BY REGEXP_SUBSTR(glgcxxsjd, '[^,]+', 1, LEVEL) IS NOT NULL
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glgcgc, '58505_gcgc' || REGEXP_SUBSTR(glgcgc, '[^,]+', 1, LEVEL), '') AS wysb
FROM tmp
CONNECT BY REGEXP_SUBSTR(glgcgc, '[^,]+', 1, LEVEL) IS NOT NULL
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glzbgl, '58505_zb' || REGEXP_SUBSTR(glzbgl, '[^,]+', 1, LEVEL), '') AS wysb
FROM tmp
CONNECT BY REGEXP_SUBSTR(glzbgl, '[^,]+', 1, LEVEL) IS NOT NULL
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glhtgl, '58505_ht' || REGEXP_SUBSTR(glhtgl, '[^,]+', 1, LEVEL), '') AS wysb
FROM tmp
CONNECT BY REGEXP_SUBSTR(glhtgl, '[^,]+', 1, LEVEL) IS NOT NULL
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(gltbgl, '58505_tb' || REGEXP_SUBSTR(gltbgl, '[^,]+', 1, LEVEL), '') AS wysb
FROM tmp
CONNECT BY REGEXP_SUBSTR(gltbgl, '[^,]+', 1, LEVEL) IS NOT NULL
AND PRIOR id = id
AND PRIOR DBMS_RANDOM.VALUE IS NOT NULL
UNION ALL
SELECT id,
NVL2(glqtgl, '58505_qt' || REGEXP_SUBSTR(glqtgl, '[^,]+', 1, LEVEL), '') AS wysb
FROM tmp
CONNECT BY REGEXP_SUBSTR(glqtgl, '[^,]+', 1, LEVEL) IS NOT NULL
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