The ARRAY_AGG function aggregates a set of elements into an array.
Invocation of the ARRAY_AGG aggregate function is based on the result array type.
>>-ARRAY_AGG--(--| element-expression |--+----------------------------------+--)->< | .-,------------------. | | V .-ASC--. | | '-ORDER BY----sort-key--+------+-+-' '-DESC-' element-expression |--+-expression--------------------------+----------------------| +-row-expression----------------------+ | .-,----------. | | V | | '-(--expression--,----expression-+--)-'
>>-ARRAY_AGG--(--index-expression--,--| element-expression |--)->< element-expression |--+-expression--------------------------+----------------------| +-row-expression----------------------+ | .-,----------. | | V | | '-(--expression--,----expression-+--)-'
The schema is SYSIBM.
If ORDER BY is specified, it determines the order of the aggregated elements in the ordinary array. If ORDER BY is not specified and no other ARRAY_AGG, LISTAGG or XMLAGG is included in the same SELECT clause with ordering specified, the ordering of elements within the ordinary array is not deterministic. If ORDER BY is not specified and the same SELECT clause has multiple occurrences of ARRAY_AGG, LISTAGG, or XMLAGG that specify ordering the same ordering of elements within the ordinary array is used for each result of ARRAY_AGG.
The result data type is an ordinary array. If the element values are specified using a single expression or row-expression, then the data type of the array element is the same as the type of the expression or row-expression. If the element values are specified with a list of expressions, then the array element is a row type with field types that correspond to the expressions.
If a SELECT clause includes an ARRAY_AGG function, then all invocations of ARRAY_AGG, LISTAGG, XMLAGG, and XMLGROUP functions in the same SELECT clause must specify the same order or not specify an order (SQLSTATE 428GZ).
There cannot be any duplicate index-expression values in the grouping set that is processed to aggregate the associative array (SQLSTATE 22545).
The result data type is an associative array. If the ARRAY_AGG is used in a context where there is a target user-defined array data type in the same statement or the result of the ARRAY_AGG is explicitly cast to a user-defined array data type, the data type of the index matches the data type of the target associative array. If the element values are specified using a single expression or row-expression, then the data type of the array element is the same as the type of the expression or row-expression. If the element values are specified with a list of expressions, then the array element is a row type with field types that correspond to the expressions.
CREATE TYPE PHONELIST AS DECIMAL(10, 0)ARRAY[10]
CREATE TABLE EMPLOYEE (
ID INTEGER NOT NULL,
PRIORITY INTEGER NOT NULL,
PHONENUMBER DECIMAL(10, 0),
PRIMARY KEY(ID, PRIORITY))
Create a procedure
that uses a SELECT INTO statement to return the prioritized list of
contact numbers under which an employee can be reached. CREATE PROCEDURE GETPHONENUMBERS
(IN EMPID INTEGER,
OUT NUMBERS PHONELIST)
BEGIN
SELECT ARRAY_AGG(PHONENUMBER ORDER BY PRIORITY)
INTO NUMBERS
FROM EMPLOYEE
WHERE ID = EMPID;
END
Create a procedure that uses a SET statement
to return the list of contact numbers for an employee, in an arbitrary
order.CREATE PROCEDURE GETPHONENUMBERS
(IN EMPID INTEGER,
OUT NUMBERS PHONELIST)
BEGIN
SET NUMBERS =
(SELECT ARRAY_AGG(PHONENUMBER)
FROM EMPLOYEE
WHERE ID = EMPID);
END
CREATE TYPE EMPPHONES AS DECIMAL(10,0) ARRAY[INTEGER]
CREATE PROCEDURE GETPHONES
(OUT EMPLOYEES EMPPHONES)
BEGIN
SELECT ARRAY_AGG(ID, PHONENUMBER)
INTO EMPLOYEES
FROM EMPLOYEE WHERE PRIORITY=1;
END
CREATE TYPE EMPROW AS ROW ANCHOR ROW EMPLOYEE
CREATE TYPE EMPARRAY AS EMPROW ARRAY[]
CREATE PROCEDURE GETEMPLOYEES
(OUT EMPLOYEES EMPARRAY)
BEGIN
SELECT ARRAY_AGG((ID, PRIORITY, PHONENUMBER) ORDER BY ID)
INTO EMPLOYEES
FROM EMPLOYEE;
END