- StarRocks
- Introduction to StarRocks
- Quick Start
- Deployment
- Deployment overview
- Prepare
- Deploy
- Deploy classic StarRocks
- Deploy and use shared-data StarRocks
- Manage
- Table Design
- Data Loading
- Concepts
- Overview of data loading
- Load data from a local file system or a streaming data source using HTTP PUT
- Load data from HDFS or cloud storage
- Continuously load data from Apache Kafka®
- Bulk load using Apache Sparkâ„¢
- Load data using INSERT
- Load data using Stream Load transaction interface
- Realtime synchronization from MySQL
- Continuously load data from Apache Flink®
- Change data through loading
- Transform data at loading
- Data Unloading
- Query Data Sources
- Query Acceleration
- Gather CBO statistics
- Synchronous materialized view
- Asynchronous materialized view
- Colocate Join
- Lateral Join
- Query Cache
- Index
- Computing the Number of Distinct Values
- Sorted streaming aggregate
- Administration
- Management
- Data recovery
- User Privilege and Authentication
- Performance Tuning
- Reference
- SQL Reference
- User Account Management
- Cluster Management
- ADD SQLBLACKLIST
- ADMIN CANCEL REPAIR TABLE
- ADMIN CHECK TABLET
- ADMIN REPAIR TABLE
- ADMIN SET CONFIG
- ADMIN SET REPLICA STATUS
- ADMIN SHOW CONFIG
- ADMIN SHOW REPLICA DISTRIBUTION
- ADMIN SHOW REPLICA STATUS
- ALTER RESOURCE GROUP
- ALTER SYSTEM
- CANCEL DECOMMISSION
- CREATE FILE
- CREATE RESOURCE GROUP
- DELETE SQLBLACKLIST
- DROP FILE
- DROP RESOURCE GROUP
- EXPLAIN
- INSTALL PLUGIN
- KILL
- SET
- SHOW BACKENDS
- SHOW BROKER
- SHOW COMPUTE NODES
- SHOW FILE
- SHOW FRONTENDS
- SHOW FULL COLUMNS
- SHOW INDEX
- SHOW PLUGINS
- SHOW PROC
- SHOW PROCESSLIST
- SHOW RESOURCE GROUP
- SHOW SQLBLACKLIST
- SHOW TABLE STATUS
- SHOW VARIABLES
- UNINSTALL PLUGIN
- DDL
- ALTER DATABASE
- ALTER MATERIALIZED VIEW
- ALTER TABLE
- ALTER VIEW
- ALTER RESOURCE
- ANALYZE TABLE
- BACKUP
- CANCEL ALTER TABLE
- CANCEL BACKUP
- CANCEL RESTORE
- CREATE ANALYZE
- CREATE DATABASE
- CREATE EXTERNAL CATALOG
- CREATE INDEX
- CREATE MATERIALIZED VIEW
- CREATE REPOSITORY
- CREATE RESOURCE
- CREATE TABLE AS SELECT
- CREATE TABLE LIKE
- CREATE TABLE
- CREATE VIEW
- CREATE FUNCTION
- DROP ANALYZE
- DROP STATS
- DROP CATALOG
- DROP DATABASE
- DROP INDEX
- DROP MATERIALIZED VIEW
- DROP REPOSITORY
- DROP RESOURCE
- DROP TABLE
- DROP VIEW
- DROP FUNCTION
- HLL
- KILL ANALYZE
- RECOVER
- REFRESH EXTERNAL TABLE
- RESTORE
- SET CATALOG
- SHOW ANALYZE JOB
- SHOW ANALYZE STATUS
- SHOW META
- SHOW RESOURCES
- SHOW FUNCTION
- TRUNCATE TABLE
- USE
- DML
- ALTER LOAD
- ALTER ROUTINE LOAD
- BROKER LOAD
- CANCEL LOAD
- CANCEL EXPORT
- CANCEL REFRESH MATERIALIZED VIEW
- CREATE ROUTINE LOAD
- DELETE
- EXPORT
- GROUP BY
- INSERT
- PAUSE ROUTINE LOAD
- REFRESH MATERIALIZED VIEW
- RESUME ROUTINE LOAD
- SELECT
- SHOW ALTER TABLE
- SHOW ALTER MATERIALIZED VIEW
- SHOW BACKUP
- SHOW CATALOGS
- SHOW CREATE CATALOG
- SHOW CREATE MATERIALIZED VIEW
- SHOW CREATE TABLE
- SHOW CREATE VIEW
- SHOW DATA
- SHOW DATABASES
- SHOW DELETE
- SHOW DYNAMIC PARTITION TABLES
- SHOW EXPORT
- SHOW LOAD
- SHOW MATERIALIZED VIEWS
- SHOW PARTITIONS
- SHOW PROPERTY
- SHOW REPOSITORIES
- SHOW RESTORE
- SHOW ROUTINE LOAD
- SHOW ROUTINE LOAD TASK
- SHOW SNAPSHOT
- SHOW TABLES
- SHOW TABLET
- SHOW TRANSACTION
- SPARK LOAD
- STOP ROUTINE LOAD
- STREAM LOAD
- SUBMIT TASK
- UPDATE
- Auxiliary Commands
- Data Types
- Keywords
- AUTO_INCREMENT
- Function Reference
- Java UDFs
- Window functions
- Lambda expression
- Aggregate Functions
- array_agg
- avg
- any_value
- approx_count_distinct
- bitmap
- bitmap_agg
- count
- grouping
- grouping_id
- hll_empty
- hll_hash
- hll_raw_agg
- hll_union
- hll_union_agg
- max
- max_by
- min
- multi_distinct_sum
- multi_distinct_count
- percentile_approx
- percentile_cont
- percentile_disc
- retention
- stddev
- stddev_samp
- sum
- variance, variance_pop, var_pop
- var_samp
- window_funnel
- Array Functions
- array_agg
- array_append
- array_avg
- array_concat
- array_contains
- array_contains_all
- array_cum_sum
- array_difference
- array_distinct
- array_filter
- array_intersect
- array_join
- array_length
- array_map
- array_max
- array_min
- array_position
- array_remove
- array_slice
- array_sort
- array_sortby
- array_sum
- arrays_overlap
- array_to_bitmap
- cardinality
- element_at
- reverse
- unnest
- Bit Functions
- Bitmap Functions
- base64_to_bitmap
- bitmap_agg
- bitmap_and
- bitmap_andnot
- bitmap_contains
- bitmap_count
- bitmap_from_string
- bitmap_empty
- bitmap_has_any
- bitmap_hash
- bitmap_intersect
- bitmap_max
- bitmap_min
- bitmap_or
- bitmap_remove
- bitmap_to_array
- bitmap_to_base64
- bitmap_to_string
- bitmap_union
- bitmap_union_count
- bitmap_union_int
- bitmap_xor
- intersect_count
- sub_bitmap
- to_bitmap
- JSON Functions
- Overview of JSON functions and operators
- JSON operators
- JSON constructor functions
- JSON query and processing functions
- Map Functions
- Binary Functions
- Conditional Functions
- Cryptographic Functions
- Date Functions
- add_months
- adddate
- convert_tz
- current_date
- current_time
- current_timestamp
- date
- date_add
- date_format
- date_slice
- date_sub, subdate
- date_trunc
- datediff
- day
- dayname
- dayofmonth
- dayofweek
- dayofyear
- days_add
- days_diff
- days_sub
- from_days
- from_unixtime
- hour
- hours_add
- hours_diff
- hours_sub
- microseconds_add
- microseconds_sub
- minute
- minutes_add
- minutes_diff
- minutes_sub
- month
- monthname
- months_add
- months_diff
- months_sub
- now
- quarter
- second
- seconds_add
- seconds_diff
- seconds_sub
- str_to_date
- str2date
- time_slice
- time_to_sec
- timediff
- timestamp
- timestampadd
- timestampdiff
- to_date
- to_days
- unix_timestamp
- utc_timestamp
- week
- week_iso
- weekofyear
- weeks_add
- weeks_diff
- weeks_sub
- year
- years_add
- years_diff
- years_sub
- Geographic Functions
- Math Functions
- String Functions
- append_trailing_char_if_absent
- ascii
- char
- char_length
- character_length
- concat
- concat_ws
- ends_with
- find_in_set
- group_concat
- hex
- hex_decode_binary
- hex_decode_string
- instr
- lcase
- left
- length
- locate
- lower
- lpad
- ltrim
- money_format
- null_or_empty
- parse_url
- repeat
- replace
- reverse
- right
- rpad
- rtrim
- space
- split
- split_part
- starts_with
- strleft
- strright
- substring
- trim
- ucase
- unhex
- upper
- Pattern Matching Functions
- Percentile Functions
- Scalar Functions
- Utility Functions
- cast function
- hash function
- System variables
- User-defined variables
- Error code
- System limits
- SQL Reference
- FAQ
- Benchmark
- Developers
- Contribute to StarRocks
- Code Style Guides
- Use the debuginfo file for debugging
- Development Environment
- Trace Tools
- Integration
ARRAY
ARRAY, as an extended type of database, is supported in various database systems such as PostgreSQL, ClickHouse, and Snowflake. ARRAY is widely used in scenarios such as A/B tests, user tag analysis, and user profiling. StarRocks supports multidimensional array nesting, array slicing, comparison, and filtering.
Define ARRAY columns
You can define an ARRAY column when you create a table.
-- Define a one-dimensional array.
ARRAY<type>
-- Define a nested array.
ARRAY<ARRAY<type>>
-- Define an array column as NOT NULL.
ARRAY<type> NOT NULL
type
specifies the data types of elements in an array. StarRocks supports the following element types: BOOLEAN, TINYINT, SMALLINT, INT, BIGINT, LARGEINT, FLOAT, DOUBLE, VARCHAR, CHAR, DATETIME, and DATE.
Elements in an array are nullable by default, for example, [null, 1 ,2]
. You cannot specify elements in an array as NOT NULL. However, you can specify an ARRAY column as NOT NULL when you create a table, such as the third example in the following code snippet.
Examples:
-- Define c1 as a one-dimensional array whose element type is INT.
create table t0(
c0 INT,
c1 ARRAY<INT>
)
duplicate key(c0)
distributed by hash(c0) buckets 3;
-- Define c1 as an nested array whose element type is VARCHAR.
create table t1(
c0 INT,
c1 ARRAY<ARRAY<VARCHAR(10)>>
)
duplicate key(c0)
distributed by hash(c0) buckets 3;
-- Define c1 as a NOT NULL array column.
create table t2(
c0 INT,
c1 ARRAY<INT> NOT NULL
)
duplicate key(c0)
distributed by hash(c0) buckets 3;
Limits
The following limits apply when you create ARRAY columns in StarRocks tables:
- In versions earlier than v2.1, you can create ARRAY columns only in Duplicate Key tables. From v2.1 onwards, you can also create ARRAY columns in other types of tables (Primary Key, Unique Key, Aggregate). Note that in an Aggregate table, you can create an ARRAY column only when the function used to aggregate data in that column is replace() or replace_if_not_null(). For more information, see Aggregate table.
- ARRAY columns cannot be used as key columns.
- ARRAY columns cannot be used as partition keys (included in PARTITION BY) or bucketing keys (included in DISTRIBUTED BY).
- DECIMAL V3 is not supported in ARRAY.
- An array can have a maximum of 14-level nesting.
Construct arrays in SQL
Arrays can be constructed in SQL using brackets []
, with each array element separated by a comma (,
).
mysql> select [1, 2, 3] as numbers;
+---------+
| numbers |
+---------+
| [1,2,3] |
+---------+
mysql> select ["apple", "orange", "pear"] as fruit;
+---------------------------+
| fruit |
+---------------------------+
| ["apple","orange","pear"] |
+---------------------------+
mysql> select [true, false] as booleans;
+----------+
| booleans |
+----------+
| [1,0] |
+----------+
StarRocks automatically infers data types if an array consists of elements of multiple types:
mysql> select [1, 1.2] as floats;
+---------+
| floats |
+---------+
| [1.0,1.2] |
+---------+
mysql> select [12, "100"];
+--------------+
| [12,'100'] |
+--------------+
| ["12","100"] |
+--------------+
You can use pointed brackets (<>
) to show the declared array type.
mysql> select ARRAY<float>[1, 2];
+-----------------------+
| ARRAY<float>[1.0,2.0] |
+-----------------------+
| [1,2] |
+-----------------------+
mysql> select ARRAY<INT>["12", "100"];
+------------------------+
| ARRAY<int(11)>[12,100] |
+------------------------+
| [12,100] |
+------------------------+
NULLs can be included in the element.
mysql> select [1, NULL];
+----------+
| [1,NULL] |
+----------+
| [1,null] |
+----------+
For an empty array, you can use pointed brackets to show the declared type, or you can write [] directly for StarRocks to infer the type based on the context. If StarRocks cannot infer the type, it will report an error.
mysql> select [];
+------+
| [] |
+------+
| [] |
+------+
mysql> select ARRAY<VARCHAR(10)>[];
+----------------------------------+
| ARRAY<unknown type: NULL_TYPE>[] |
+----------------------------------+
| [] |
+----------------------------------+
mysql> select array_append([], 10);
+----------------------+
| array_append([], 10) |
+----------------------+
| [10] |
+----------------------+
Load Array data
StarRocks supports loading Array data in three ways:
- INSERT INTO is suitable for loading small-scale data for testing.
- Broker Load is suitable for loading ORC or Parquet files with large-scale data.
- Stream Load and Routine Load are suitable for loading CSV files with large-scale data.
Use INSERT INTO to load arrays
You can use INSERT INTO to load small-scale data column by column, or perform ETL on data before loading the data.
create table t0(
c0 INT,
c1 ARRAY<INT>
)
duplicate key(c0)
distributed by hash(c0) buckets 3;
INSERT INTO t0 VALUES(1, [1,2,3]);
Use Broker Load to load arrays from ORC or Parquet files
The array type in StarRocks corresponds to the list structure in ORC and Parquet files, which eliminates the need for you to specify different data types in StarRocks. For more information about data loading, see Broker load.
Use Stream Load or Routine Load to load CSV-formatted arrays
Arrays in CSV files are separated with comma by default. You can use Stream Load or Routine Load to load CSV text files or CSV data in Kafka.
Query ARRAY data
You can access elements in an array using []
and subscripts, starting from 1
.
mysql> select [1,2,3][1];
+------------+
| [1,2,3][1] |
+------------+
| 1 |
+------------+
1 row in set (0.00 sec)
If the subscript is 0 or a negative number, no error is reported and NULL is returned.
mysql> select [1,2,3][0];
+------------+
| [1,2,3][0] |
+------------+
| NULL |
+------------+
1 row in set (0.01 sec)
If the subscript exceeds the length of the array (the number of elements in the array), NULL will be returned.
mysql> select [1,2,3][4];
+------------+
| [1,2,3][4] |
+------------+
| NULL |
+------------+
1 row in set (0.01 sec)
For multidimensional arrays, the elements can be accessed recursively.
mysql(ARRAY)> select [[1,2],[3,4]][2];
+------------------+
| [[1,2],[3,4]][2] |
+------------------+
| [3,4] |
+------------------+
1 row in set (0.00 sec)
mysql> select [[1,2],[3,4]][2][1];
+---------------------+
| [[1,2],[3,4]][2][1] |
+---------------------+
| 3 |
+---------------------+
1 row in set (0.01 sec)