Joins the elements of an array into a string. The function converts all elements in the array to strings and then concatenates them with the specified separator.
array_join(ARRAY<T> arr, STRING separator [, STRING null_replacement])
arr:ARRAY type, the array to be joinedseparator:STRING type, required parameter, the separator used to separate array elementsnull_replacement:STRING type, optional parameter, the string used to replace null values in the array. If this parameter is not provided, null values will be skippedSupported types for T:
Return type: STRING
Return value meaning:
Usage notes:
null_replacement parameter is provided, null elements will be replaced with that stringnull_replacement parameter is not provided, null elements will be skippedQuery Examples:
Join arrays with a separator:
SELECT array_join([1, 2, 3, 4, 5], ','); +--------------------------------------+ | array_join([1, 2, 3, 4, 5], ',') | +--------------------------------------+ | 1,2,3,4,5 | +--------------------------------------+
Join string arrays with a space separator:
SELECT array_join(['hello', 'world', 'doris'], ' '); +--------------------------------------------------+ | array_join(['hello', 'world', 'doris'], ' ') | +--------------------------------------------------+ | hello world doris | +--------------------------------------------------+
Join arrays containing null values (null values are skipped):
SELECT array_join([1, null, 3, null, 5], '-'); +--------------------------------------------+ | array_join([1, null, 3, null, 5], '-') | +--------------------------------------------+ | 1-3-5 | +--------------------------------------------+
Replace null values using the null_replacement parameter:
SELECT array_join([1, null, 3, null, 5], '-', 'NULL'); +--------------------------------------------------+ | array_join([1, null, 3, null, 5], '-', 'NULL') | +--------------------------------------------------+ | 1-NULL-3-NULL-5 | +--------------------------------------------------+
Join float arrays:
SELECT array_join([1.1, 2.2, 3.3], ' | '); +------------------------------------------+ | array_join([1.1, 2.2, 3.3], ' | ') | +------------------------------------------+ | 1.1 | 2.2 | 3.3 | +------------------------------------------+
Join date arrays:
SELECT array_join(CAST(['2023-01-01', '2023-06-15', '2023-12-31'] AS ARRAY<DATETIME>), ' to '); +-----------------------------------------------------------------------------------------+ | array_join(CAST(['2023-01-01', '2023-06-15', '2023-12-31'] AS ARRAY<DATETIME>), ' to ') | +-----------------------------------------------------------------------------------------+ | 2023-01-01 00:00:00 to 2023-06-15 00:00:00 to 2023-12-31 00:00:00 | +-----------------------------------------------------------------------------------------+
Join IP address arrays:
SELECT array_join(CAST(['192.168.1.1', '192.168.1.2', '192.168.1.3'] AS ARRAY<IPV4>), ' -> '); +----------------------------------------------------------------------------------+ | array_join(CAST(['192.168.1.1', '192.168.1.2', '192.168.1.3'] AS ARRAY<IPV4>), ' -> ') | +----------------------------------------------------------------------------------+ | 192.168.1.1 -> 192.168.1.2 -> 192.168.1.3 | +----------------------------------------------------------------------------------+
Empty arrays return empty strings:
SELECT array_join([], ','); +----------------------+ | array_join([], ',') | +----------------------+ | | +----------------------+
NULL arrays return NULL:
SELECT array_join(NULL, ','); +----------------------+ | array_join(NULL, ',') | +----------------------+ | NULL | +----------------------+
Error when passing complex types:
SELECT array_join([{'name':'Alice','age':20}, {'name':'Bob','age':30}], '; '); ERROR 1105 (HY000): errCode = 2, detailMessage = can not cast from origin type ARRAY<MAP<TEXT,TEXT>> to target type=ARRAY<VARCHAR(65533)>
Error with wrong number of parameters:
SELECT array_join([1,2,3], ',', 'extra', 'too_many'); ERROR 1105 (HY000): errCode = 2, detailMessage = Can not found function 'array_join' which has 4 arity. Candidate functions are: [array_join(Expression, Expression, Expression), array_join(Expression, Expression)]
Error when passing non-array types:
SELECT array_join('not_an_array', ','); ERROR 1105 (HY000): errCode = 2, detailMessage = Can not find the compatibility function signature: array_join(VARCHAR(12), VARCHAR(1))
ARRAY, JOIN, ARRAY_JOIN