Checks whether an array contains a specified value. Returns true if found, false otherwise. If the array is NULL, returns NULL.
array_contains(ARRAY<T> arr, T value)
arr:ARRAY type, the array to check. Supports column names or constant values.value:T type, the value to search for. Type must be compatible with array element type.T supported types:
Return type: BOOLEAN
Return value meaning:
Return value behavior description:
Boundary condition behavior:
Exception value behavior:
Cases that return NULL:
Type compatibility rules:
Table creation example
CREATE TABLE array_contains_test ( id INT, int_array ARRAY<INT>, string_array ARRAY<STRING> ) DUPLICATE KEY(id) DISTRIBUTED BY HASH(id) BUCKETS 3 PROPERTIES ( "replication_num" = "1" ); -- Insert test data INSERT INTO array_contains_test VALUES (1, [1000, 2000, 3000], ['apple', 'banana', 'cherry']), (2, [], []), (3, NULL, NULL), (4, [1000, null, 3000], ['apple', null, 'cherry']);
Query examples:
Check if an array contains a specific integer value: This example returns false because 5 is not in int_array.
SELECT array_contains(int_array, 5) FROM array_contains_test WHERE id = 1; +-------------------------------+ | array_contains(int_array, 5) | +-------------------------------+ | 0 | +-------------------------------+
Check if a string array contains a specific string: This example returns true because ‘banana’ is in string_array.
SELECT array_contains(string_array, 'banana') FROM array_contains_test WHERE id = 1; +------------------------------------------+ | array_contains(string_array, 'banana') | +------------------------------------------+ | 1 | +------------------------------------------+
Currently it is an empty array. This example returns false because there are no values in the empty array.
SELECT array_contains(int_array, 1000) FROM array_contains_test WHERE id = 2; +----------------------------------+ | array_contains(int_array, 1000) | +----------------------------------+ | 0 | +----------------------------------+
Currently it is a NULL array, this example returns NULL.
SELECT array_contains(int_array, 1000) FROM array_contains_test WHERE id = 3; +----------------------------------+ | array_contains(int_array, 1000) | +----------------------------------+ | NULL | +----------------------------------+
Check if an array contains null In this example, the value_expr parameter is null, and there are no null elements in the array, so it returns false.
SELECT array_contains([1, 2, 3], null); +---------------------------------+ | array_contains([1, 2, 3], null) | +---------------------------------+ | 0 | +---------------------------------+
Check if an array contains null In this example, the value_expr parameter is null, and the array contains SQL null values, so it returns true.
SELECT array_contains([null, 1, 2], null); +------------------------------------+ | array_contains([null, 1, 2], null) | +------------------------------------+ | 1 | +------------------------------------+
When the search value type is incompatible with array element type, returns false.
SELECT array_contains([1, 2, 3], 'string'); +-------------------------------------+ | array_contains([1, 2, 3], 'string') | +-------------------------------------+ | 0 | +-------------------------------------+
When the search value type cannot be type-converted with array elements, an error is returned
SELECT array_contains([1, 2, 3], [4, 5, 6]); ERROR 1105 (HY000): errCode = 2, detailMessage = can not cast from origin type ARRAY<TINYINT> to target type=TINYINT
Unsupported complex types will throw an error. In this example, the array is a nested array type, returning an unsupported error.
SELECT array_contains([[1,2],[2,3]], [1,2]); ERROR 1105 (HY000): errCode = 2, detailMessage = (10.16.10.6)[RUNTIME_ERROR]execute failed or unsupported types for function array_contains(Array(Nullable(Array(Nullable(TINYINT)))), Array(Nullable(TINYINT)))
Performance considerations: When dealing with large arrays, if performance is a major concern, you can use inverted indexes for accelerated queries, but there are some usage restrictions to note:
-- Table creation example CREATE TABLE `test_array_index` ( `apply_date` date NULL COMMENT '', `id` varchar(60) NOT NULL COMMENT '', `inventors` array<text> NULL COMMENT '' -- Add non-tokenized inverted index to array column when creating table ) ENGINE=OLAP DUPLICATE KEY(`apply_date`, `id`) COMMENT 'OLAP' DISTRIBUTED BY HASH(`id`) BUCKETS 1 PROPERTIES ( "replication_allocation" = "tag.location.default: 1", "is_being_synced" = "false", "storage_format" = "V2", "light_schema_change" = "true", "disable_auto_compaction" = "false", "enable_single_replica_compaction" = "false" ); -- Query example SELECT id, inventors FROM test_array_index WHERE array_contains(inventors, 'x') ORDER BY id;
ARRAY, CONTAIN, CONTAINS, ARRAY_CONTAINS