Returns elements that exist in the first array but not in the second array, forming a new array after deduplication while maintaining the original order.
array_except(ARRAY<T> arr1, ARRAY<T> arr2)
arr1:ARRAY type, the first array.arr2:ARRAY type, the second array.T supported types:
Return type: ARRAY
Return value meaning:
Usage notes:
CREATE TABLE array_except_test ( id INT, arr1 ARRAY<INT>, arr2 ARRAY<INT>, str_arr1 ARRAY<STRING>, str_arr2 ARRAY<STRING> ) DUPLICATE KEY(id) DISTRIBUTED BY HASH(id) BUCKETS 3 PROPERTIES ( "replication_num" = "1" ); INSERT INTO array_except_test VALUES (1, [1, 2, 3, 4, 5], [2, 4]), (2, [10, 20, 30], [30, 40]), (3, [], [1, 2]), (4, NULL, [1, 2]), (5, [1, null, 2, null, 3], [null, 2]), (6, [1, 2, 3], NULL), (7, [1, 2, 3], []), (8, [], []), (9, [1, 2, 2, 3, 3, 3, 4, 5, 5], [2, 3, 5]), (10, [1], [1]);
Query examples:
Basic integer array except:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 1; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [1, 3, 5] | +-----------------------------+
Partial element overlap:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 2; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [10, 20] | +-----------------------------+
Empty array with any array:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 3; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [] | +-----------------------------+
NULL array: returning NULL when either input array is NULL without throwing an error.
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 4; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | NULL | +-----------------------------+
Array containing null values:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 5; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [1, 3] | +-----------------------------+
Second array is NULL: returning NULL when either input array is NULL without throwing an error.
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 6; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | NULL | +-----------------------------+
Second array is empty:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 7; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [1, 2, 3] | +-----------------------------+
Both arrays are empty:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 8; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [] | +-----------------------------+
Deduplication example:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 9; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [1, 4] | +-----------------------------+
All elements are excepted:
SELECT array_except(arr1, arr2) FROM array_except_test WHERE id = 10; +-----------------------------+ | array_except(arr1, arr2) | +-----------------------------+ | [] | +-----------------------------+
String array except:
SELECT array_except(['a', 'b', 'c', 'd'], ['b', 'd']); +----------------------------------+ | array_except(['a','b','c','d'],['b','d']) | +----------------------------------+ | ["a", "c"] | +----------------------------------+
Incorrect number of parameters:
SELECT array_except([1, 2, 3]); ERROR 1105 (HY000): errCode = 2, detailMessage = Can not found function 'array_except' which has 1 arity. Candidate functions are: [array_except(Expression, Expression)]
Incompatible types:
SELECT array_except([1, 2, 3], ['a', 'b']); ERROR 1105 (HY000): errCode = 2, detailMessage = Can not find the compatibility function signature: array_except(ARRAY<INT>, ARRAY<VARCHAR(1)>)
Passing non-array type:
SELECT array_except('not_an_array', [1, 2, 3]); ERROR 1105 (HY000): errCode = 2, detailMessage = Can not find the compatibility function signature: array_except(VARCHAR(12), ARRAY<INT>)
Complex types not supported:
SELECT array_except([[1,2],[3,4]], [[3,4]]); ERROR 1105 (HY000): errCode = 2, detailMessage = Can not find the compatibility function signature: array_except(ARRAY<ARRAY<INT>>, ARRAY<ARRAY<INT>>)
ARRAY, EXCEPT, ARRAY_EXCEPT