— 原始数据
— a 111
— b 222
— a 333
— a 444
— b 555
— 最终结果
— a 111*333*444
SELECT L4.L_TIME ,MAX(SUBSTR(L4.分组内容,2)) 最终字段值 FROM( SELECT L3.L_TIME ,SYS_CONNECT_BY_PATH(L3.L_CONTENT,'*') AS 分组内容 FROM( SELECT L2.L_TIME ,L2.L_CONTENT ,L2.L_TIME||L2.分组内编号 AS 分组字段加编号,L2.L_TIME||(L2.分组内编号-1) AS 上级分组字段加编号 FROM( SELECT L1.L_TIME -- 分组依据 ,L1.L_CONTENT -- 同一列中 要合并的不同行 的值 ,ROW_NUMBER() OVER (PARTITION BY L1.L_TIME ORDER BY L1.L_CONTENT ASC) 分组内编号 FROM LOGS L1 ) L2 ) L3 START WITH L3.上级分组字段加编号 LIKE '%0' CONNECT BY PRIOR L3.分组字段加编号=L3.上级分组字段加编号 ) L4 WHERE L_TIME='111' GROUP BY L4.L_TIME -- ROW_NUMBER() OVER(PARTITION BY A ORDER BY B DESC) 新列名 -- 根据A分组,在分组内部根据B排序,而此函数计算的值就表示每组内部排序后的顺序编号(组内连续的唯一的) -- SYS_CONNECT_BY_PATH 函数: 第一个参数是形成树形式的字段,第二个参数是父级和其子级分隔显示用的分隔符 -- CONNECT BY PRIOR 是标示父子关系的对应 -- START WITH 代表你要开始遍历的的节点 ------------------------------------------------------------------------------------------ ------------------------------------------------------------------------------------------ 附上建表语句: DROP TABLE LOGS; CREATE TABLE LOGS ( L_ID VARCHAR2(32) NOT NULL , L_CONTENT VARCHAR2(512) , L_TIME VARCHAR2(32) , L_USER VARCHAR2(32) , PRIMARY KEY (L_ID) ); COMMENT ON TABLE LOGS IS '日志表'; COMMENT ON COLUMN LOGS.L_ID IS '日志ID'; COMMENT ON COLUMN LOGS.L_CONTENT IS '日志内容'; COMMENT ON COLUMN LOGS.L_TIME IS '时间'; COMMENT ON COLUMN LOGS.L_USER IS '操作人'; INSERT INTO LOGS (L_ID, L_CONTENT, L_TIME, L_USER) VALUES ('123', '黑啊', '111', '12345'); INSERT INTO LOGS (L_ID, L_CONTENT, L_TIME, L_USER) VALUES ('124', '白啊', '222', '123456'); INSERT INTO LOGS (L_ID, L_CONTENT, L_TIME, L_USER) VALUES ('125', '黑白啊', '111', '1234567'); INSERT INTO LOGS (L_ID, L_CONTENT, L_TIME, L_USER) VALUES ('126', '白白啊', '111', '12345'); INSERT INTO LOGS (L_ID, L_CONTENT, L_TIME, L_USER) VALUES ('127', '嘿嘿啊', '222', '123456');
嘿嘿嘿