HEAVY.AI supports arrays in dictionary-encoded text and number fields (TINYINT, SMALLINT, INTEGER, BIGINT, FLOAT, and DOUBLE). Data stored in arrays are not normalized. For example, {green,yellow} is not the same as {yellow,green}. As with many SQL-based services, OmniSci array indexes are 1-based.
HEAVY.AI supports NULL variable-length arrays for all integer and floating-point data types, including dictionary-encoded string arrays. For example, you can insert NULL into BIGINT[ ], DOUBLE[ ], or TEXT[ ] columns. HEAVY.AI supports NULL fixed-length arrays for all integer and floating-point data types, but not for dictionary-encoded string arrays. For example, you can insert NULL into BIGINT[2] DOUBLE[3], but not into TEXT[2] columns.
Expression
Description
ArrayCol[n] ...
Returns value(s) from specific location n in the array.
UNNEST(ArrayCol)
Extract the values in the array to a set of rows. Requires GROUP BY; projecting UNNEST is not currently supported.
test = ANY ArrayCol
ANY compares a scalar value with a single row or set of values in an array, returning results in which at least one item in the array matches. ANY must be preceded by a comparison operator.
test = ALL ArrayCol
ALL compares a scalar value with a single row or set of values in an array, returning results in which all records in the array field are compared to the scalar value. ALL must be preceded by a comparison operator.
CARDINALITY()
Returns the number of elements in an array. For example:
omnisql>SELECT UNNEST(colors) AS c FROM test_array;Exception: UNNEST notsupportedin the projection list yet.
omnisql>SELECT UNNEST(colors) AS c, count(*) FROM test_array group by c;c|EXPR$1green|4yellow|3red|4black|2white|2
omnisql>SELECTname, colors [2] FROM test_array;name|EXPR$1Banana|yellowCherry|blackOlive|blackOnion|whitePepper|greenRadish|whiteRutabaga|NULLZucchini|yellow
omnisql>SELECTname, colors FROM test_array WHERE colors[1]='green';name|colorsBanana|{green, yellow}Olive|{green, black}Zucchini|{green, yellow}
omnisql>SELECT*FROM test_array WHERE colors ISNULL;name|colors|qtyRutabaga|NULL|{}
The following queries use arrays in an INTEGER field:
omnisql>SELECTname, qty FROM test_array WHERE qty[2] >1;name|qtyBanana|{1, 2}Pepper|{1, 2, 3}
omnisql>SELECTname, qty FROM test_array WHERE15< ALL qty;Norows returned.
omnisql>SELECTname, qty FROM test_array WHERE2= ANY qty;name|qtyBanana|{1, 2}Pepper|{1, 2, 3}
omnisql>SELECTCOUNT(*) FROM test_array WHERE qty IS NOT NULL;EXPR$08
omnisql>SELECTCOUNT(*) FROM test_array WHERE CARDINALITY(qty)<0;EXPR$06