用指定的separator做分隔字元,串連colname中的值。
注意事項
升級到MaxCompute 2.0後,產品擴充了部分函數。如果您用到的函數涉及新資料類型(TINYINT、SMALLINT、INT、FLOAT、VARCHAR、TIMESTAMP或BINARY),在使用擴充函數時,需要執行如下語句開啟新資料類型開關:
在同一條SQL語句中同時使用多個彙總函式時,如果專案資源不足,會出現記憶體溢出問題,請您根據實際業務情況最佳化SQL或購買計算資源。
命令格式
string wm_concat(string <separator>, string <colname>)
參數說明
separator:必填。STRING類型常量,分隔字元。
colname:必填。STRING類型。如果輸入為BIGINT、DOUBLE或DATETIME類型,會隱式轉換為STRING類型後參與運算。
當WM_CONCAT函數同時攜帶within group (order by <col1>[,<col2>…])
運算式和DISTINCT關鍵字時,需注意文法的使用,詳情請參見彙總函式文法。
傳回值說明
使用group by
分組,組內傳回值不排序。
返回STRING類型。返回規則如下:
separator非STRING類型常量時,返回報錯。
colname非STRING、BIGINT、DOUBLE或DATETIME類型時,返回報錯。
colname值為NULL時,該行不會參與計算。
select wm_concat(',', name) from table_name;
語句中,如果table_name
為空白集合,該語句返回NULL值。
樣本資料
為便於理解各函數的使用方法,本文為您提供來源資料,基於來源資料提供函數相關樣本。建立表emp,並添加資料,命令樣本如下:
create table if not exists emp
(empno bigint,
ename string,
job string,
mgr bigint,
hiredate datetime,
sal bigint,
comm bigint,
deptno bigint);
tunnel upload emp.txt emp; --請根據您上傳資料檔案的實際path(路徑以及名稱)替換emp.txt
emp.txt中的資料如下:
7369,SMITH,CLERK,7902,1980-12-17 00:00:00,800,,20
7499,ALLEN,SALESMAN,7698,1981-02-20 00:00:00,1600,300,30
7521,WARD,SALESMAN,7698,1981-02-22 00:00:00,1250,500,30
7566,JONES,MANAGER,7839,1981-04-02 00:00:00,2975,,20
7654,MARTIN,SALESMAN,7698,1981-09-28 00:00:00,1250,1400,30
7698,BLAKE,MANAGER,7839,1981-05-01 00:00:00,2850,,30
7782,CLARK,MANAGER,7839,1981-06-09 00:00:00,2450,,10
7788,SCOTT,ANALYST,7566,1987-04-19 00:00:00,3000,,20
7839,KING,PRESIDENT,,1981-11-17 00:00:00,5000,,10
7844,TURNER,SALESMAN,7698,1981-09-08 00:00:00,1500,0,30
7876,ADAMS,CLERK,7788,1987-05-23 00:00:00,1100,,20
7900,JAMES,CLERK,7698,1981-12-03 00:00:00,950,,30
7902,FORD,ANALYST,7566,1981-12-03 00:00:00,3000,,20
7934,MILLER,CLERK,7782,1982-01-23 00:00:00,1300,,10
7948,JACCKA,CLERK,7782,1981-04-12 00:00:00,5000,,10
7956,WELAN,CLERK,7649,1982-07-20 00:00:00,2450,,10
7956,TEBAGE,CLERK,7748,1982-12-30 00:00:00,1300,,10
樣本
樣本1:對所有職工的姓名(ename)進行合并。命令樣本如下:
select wm_concat(',', ename) from emp;
返回結果如下:
+------------+ | _c0 | +------------+ | SMITH,ALLEN,WARD,JONES,MARTIN,BLAKE,CLARK,SCOTT,KING,TURNER,ADAMS,JAMES,FORD,MILLER,JACCKA,WELAN,TEBAGE | +------------+
樣本2:與
group by
配合使用,對所有職工按照部門(deptno)進行分組,並將同組的職工姓名(ename)進行合并。命令樣本如下:select deptno, wm_concat(',', ename) from emp group by deptno order by deptno;
返回結果如下:
+------------+------------+ | deptno | _c1 | +------------+------------+ | 10 | CLARK,KING,MILLER,JACCKA,WELAN,TEBAGE | | 20 | SMITH,JONES,SCOTT,ADAMS,FORD | | 30 | ALLEN,WARD,MARTIN,BLAKE,TURNER,JAMES | +------------+------------+
樣本3:與
group by
配合使用,對所有職工按照部門(deptno)進行分組,並將同組的薪資(sal)去重後進行合并。命令樣本如下:select deptno, wm_concat(distinct ',', sal) from emp group by deptno order by deptno;
返回結果如下:
+------------+------------+ | deptno | _c1 | +------------+------------+ | 10 | 1300,2450,5000 | | 20 | 1100,2975,3000,800 | | 30 | 1250,1500,1600,2850,950 | +------------+------------+
樣本4:與
group by
、order by
配合使用,對所有職工按照部門(deptno)進行分組,並將同組的薪資(sal)進行合并排序。命令樣本如下:select deptno, wm_concat(',',sal) within group (order by sal) from emp group by deptno order by deptno;
返回結果如下:
+------------+------------+ |deptno|_c1| +------------+------------+ |10|1300,1300,2450,2450,5000,5000| |20|800,1100,2975,3000,3000| |30|950,1250,1250,1500,1600,2850| +------------+------------+
樣本5:與
group by
、order by
配合使用,對指定列進行排序。命令樣本如下:SELECT g, wm_concat ('#', t) WITHIN GROUP (ORDER BY h DESC) AS t_t FROM VALUES ("24",1,10), ("234",2,100), ("555",1,20), ("123", 2,30), ("7",1,11), ("13",3,50) AS tmp (t,g,h) GROUP BY g;
返回結果如下:
+------+-----+ | g | t_t | +------+-----+ | 1 | 555#7#24 | | 2 | 234#123 | | 3 | 13 | +------+-----+
相關函數
WM_CONCAT函數屬於彙總函式,更多將多條輸入記錄進行求平均值、參數彙總的相關函數請參見彙總函式。