- Introduction
- Quick Start
- Table Design
- Data Loading
- Overview of data loading
- Load data from a local file system or a streaming data source using HTTP push
- Load data from HDFS or cloud storage
- Routine Load
- Spark Load
- Insert Into
- Change data through loading
- Transform data at loading
- Json Loading
- Synchronize data from MySQL
- Load data by using flink-connector-starrocks
- DataX Writer
- Data Export
- Using StarRocks
- Reference
- SQL Reference
- User Account Management
- Cluster Management
- ADMIN CANCEL REPAIR
- ADMIN CHECK TABLET
- ADMIN REPAIR
- ADMIN SET CONFIG
- ADMIN SET REPLICA STATUS
- ADMIN SHOW CONFIG
- ADMIN SHOW REPLICA DISTRIBUTION
- ADMIN SHOW REPLICA STATUS
- ALTER SYSTEM
- CANCEL DECOMMISSION
- CREATE FILE
- DROP FILE
- INSTALL PLUGIN
- SHOW BACKENDS
- SHOW BROKER
- SHOW FILE
- SHOW FRONTENDS
- SHOW FULL COLUMNS
- SHOW INDEX
- SHOW PLUGINS
- SHOW TABLE STATUS
- UNINSTALL PLUGIN
- DDL
- ALTER DATABASE
- ALTER TABLE
- ALTER VIEW
- BACKUP
- CANCEL BACKUP
- CANCEL RESTORE
- CREATE DATABASE
- CREATE INDEX
- CREATE MATERIALIZED VIEW
- CREATE REPOSITORY
- CREATE RESOURCE
- CREATE TABLE AS SELECT
- CREATE TABLE LIKE
- CREATE TABLE
- CREATE VIEW
- CREATE FUNCTION
- DROP DATABASE
- DROP INDEX
- DROP MATERIALIZED VIEW
- DROP REPOSITORY
- DROP RESOURCE
- DROP TABLE
- DROP VIEW
- DROP FUNCTION
- HLL
- RECOVER
- RESTORE
- SHOW RESOURCES
- SHOW FUNCTION
- TRUNCATE TABLE
- DML
- ALTER ROUTINE LOAD
- BROKER LOAD
- CANCEL LOAD
- DELETE
- EXPORT
- GROUP BY
- INSERT
- PAUSE ROUTINE LOAD
- RESUME ROUTINE LOAD
- ROUTINE LOAD
- SELECT
- SHOW ALTER
- SHOW BACKUP
- SHOW DATA
- SHOW DATABASES
- SHOW DELETE
- SHOW DYNAMIC PARTITION TABLES
- SHOW EXPORT
- SHOW LOAD
- 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
- Data Types
- Auxiliary Commands
- Function Reference
- Java UDFs
- Window Function
- Date Functions
- convert_tz
- curdate
- current_timestamp
- curtime
- datediff
- date_add
- date_format
- date_sub
- date_trunc
- day
- dayname
- dayofmonth
- dayofweek
- dayofyear
- from_days
- from_unixtime
- hour
- minute
- month
- monthname
- now
- quarter
- second
- str_to_date
- timediff
- timestampadd
- timestampdiff
- to_date
- to_days
- unix_timestamp
- utc_timestamp
- weekofyear
- year
- hours_diff
- minutes_diff
- months_diff
- seconds_diff
- weeks_diff
- years_diff
- Aggregate Functions
- Geographic Functions
- String Functions
- JSON Functions
- Overview of JSON functions and operators
- JSON constructor functions
- JSON query and processing functions
- JSON operators
- Aggregate Functions
- Bitmap Functions
- Array Functions
- cast function
- hash function
- Cryptographic Functions
- Math Functions
- Utility Functions
- System variables
- Error code
- System limits
- SQL Reference
- Administration
- FAQ
- Deploy
- Data Migration
- SQL
- Other FAQs
- Benchmark
- Developers
- Contribute to StarRocks
- Code Style Guides
- Use the debuginfo file for debugging
- Development Environment
- Trace Tools
Arrays
Background
Arrays, as an extended type of database, are supported in PG, ClickHouse, Snowflake and other systems. They can be widely used in scenarios such as A/B tests, user tag analysis, and crowd profilings. StarRocks supports multidimensional array nesting, array slicing, comparison, and filtering.
Array usage
Array definition
The following is an example of defining an array column in StarRocks:
-- One-dimensional arrays
create table t0(
c0 INT,
c1 `ARRAY<INT>`
)
duplicate key(c0);
-- Define nested arrays
create table t1(
c0 INT,
c1 `ARRAY<ARRAY<VARCHAR(10)>>`
)
duplicate key(c0);
As above, the array column is defined in the form of ARRAY
and its TYPE
has a default value of nullable
. Currently, StarRocks does not support specifying TYPE
as NOT NULL
, but you can define the array itself as NOT NULL
.
create table t2(
c0 INT,
c1 `ARRAY<INT>` NOT NULL
)
duplicate key(c0)
The array type has the following restrictions:
- The array columns can be only defined in duplicate tables
- Array columns cannot be used as key columns (may be supported later)
- Array columns cannot be used as distribution columns
- Array columns cannot be used as partition columns
Construct arrays in SQL
Arrays can be constructed in SQL using brackets ("[" and "]"), with each array element separated by a comma (",")
select [1, 2, 3] as numbers;
select ["apple", "orange", "pear"] as fruit;
select [true, false] as booleans;
When array elements have different types, StarRocks will automatically derive the appropriate type (supertype)
select [1, 1.2] as floats;
select [12, "100"]; -- The result is ["12", "100"].
You can use pointed brackets (<>
) to show the declared array type.
select `ARRAY<float>`[1, 2];
select `ARRAY<INT>`["12", "100"]; -- The result is [12, 100].
NULL can be included in the element
select [1, NULL];
For empty arrays, 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 can’t infer the type, it will report an error.
select [];
select `ARRAY<VARCHAR(10)>`[];
select array_append([], 10);
Array import
There are three ways to write array values to StarRocks. Insert into is suitable for small-scale data testing. ORC Parquet inport and CSV import are suitable for large-scale data import.
INSERT INTO
create table t0(c0 INT, c1 `ARRAY<INT>`)duplicate key(c0); INSERT INTO t0 VALUES(1, [1,2,3]);
Import from ORC Parquet file
The array type in StarRocks corresponds to the list structure in ORC/Parquet format; no additional specification is needed. Currently ORC list structure can be imported directly.
Import from CSV file
The array of CSV files is separated by comma by default. You can use stream load or routine load to import CSV files or CSV format data in Kafka.
Array element access
Access an element of an array using [ ]
and subscripts, starting with 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 will be reported and NULL will be returned
mysql> select [1,2,3][0];
+------------+
| [1,2,3][0] |
+------------+
| NULL |
+------------+
1 row in set (0.01 sec)
If the subscript exceeds the size of 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 internal 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)