WMSYS.WM_CONCAT/WM_CONCAT

2023-10-31 11:17:11  Updated

Purpose

WMSYS.WM_CONCAT/WM_CONCAT() aggregates data from a number of measure columns into a single row. You can use this function as an aggregate or analytic function.

Note

  • When you use this function as an analytic function, use the OVER clause to define a window over the data on which the function operates. This function divides the query result set into groups based on one or more expressions in query_partition_clause.
  • When you use it as an aggregate function, you do not need to add the OVER keyword.
    • As a single-set aggregate function, the WM_CONCAT function operates on all rows and returns a single output row.
    • As a group-set aggregate function, the WM_CONCAT function operates on each group specified in the GROUP BY clause and returns an output row.

Syntax

WM_CONCAT ([DISTINCT] measure_expr) [OVER query_partition_clause]

Parameters

Parameter Description
DISTINCT If you specify the DISTINCT operator, duplicates are eliminated from the result set. This parameter is optional.
measure_expr An expression of any type. NULLs in the measure column are ignored.
OVER You can use the OVER clause to define a window over the data on which the function operates. For more information, see Analytic functions.

Return type

This function returns data values of the CLOB data type.

Examples

The table employees has been created.

obclient> SELECT * FROM employees;
+---------------+-----------+------------+--------+
| DEPARTMENT_ID | LAST_NAME | HIREDATE   | SALARY |
+---------------+-----------+------------+--------+
|            30 | Raphaely  | 2017-07-01 |   1700 |
|            30 | De Haan   | 2018-05-01 |  11000 |
|            40 | Errazuriz | 2017-07-21 |   1400 |
|            50 | Hartstein | 2019-10-05 |  14000 |
|            50 | Raphaely  | 2017-07-22 |   1700 |
|            50 | Weiss     | 2019-10-05 |  13500 |
|            90 | Russell   | 2019-07-11 |  13000 |
|            90 | Partners  | 2018-12-01 |  14000 |
+---------------+-----------+------------+--------+
8 rows in set

Example of an aggregate function

Aggregate all names in the last_name column into a single row.

obclient> SELECT WM_CONCAT(last_name) "Emp_list" FROM employees;
+----------------------------------------------------------------------+
| Emp_list                                                             |
+----------------------------------------------------------------------+
| Raphaely,De Haan,Errazuriz,Hartstein,Raphaely,Weiss,Russell,Partners |
+----------------------------------------------------------------------+
1 row in set

Example of an analytic function

Group the data records in the table by the department_id column. Return all last_name in the group.

obclient> SELECT department_id,hiredate,last_name,
              WM_CONCAT(last_name) OVER (PARTITION BY department_id) as "Emp_list"
    FROM employees
    ORDER BY 1,2;
+---------------+------------+-----------+--------------------------+
| DEPARTMENT_ID | HIREDATE   | LAST_NAME | Emp_list                 |
+---------------+------------+-----------+--------------------------+
|            30 | 2017-07-01 | Raphaely  | Raphaely,De Haan         |
|            30 | 2018-05-01 | De Haan   | Raphaely,De Haan         |
|            40 | 2017-07-21 | Errazuriz | Errazuriz                |
|            50 | 2017-07-22 | Raphaely  | Hartstein,Raphaely,Weiss |
|            50 | 2019-10-05 | Hartstein | Hartstein,Raphaely,Weiss |
|            50 | 2019-10-05 | Weiss     | Hartstein,Raphaely,Weiss |
|            90 | 2018-12-01 | Partners  | Russell,Partners         |
|            90 | 2019-07-11 | Russell   | Russell,Partners         |
+---------------+------------+-----------+--------------------------+
8 rows in set

Contact Us