- 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
BINARY/VARBINARY
Description
BINARY(M)
VARBINARY(M)
Since v3.0, StarRocks supports the BINARY/VARBINARY data type, which is used to store binary data. The maximum supported length is the same as VARCHAR (1~1048576). The unit is byte. If M
is not specified, 1048576 is used by default. Binary data types contain byte strings while character data types contain character strings.
BINARY is an alias of VARBINARY. The usage is the same as VARBINARY.
Limits and usage notes
VARBINARY columns are supported in Duplicate Key, Primary Key, and Unique Key tables. They are not supported in Aggregate tables.
VARBINARY columns cannot be used as partition keys, bucketing keys, or dimension columns of Duplicate Key, Primary Key, and Unique Key tables. They cannot be used in ORDER BY, GROUP BY, and JOIN clauses.
BINARY(M)/VARBINARY(M) are not right-padded in the case of unaligned length.
Examples
Create a column of VARBINARY type
When creating a table, use the keyword VARBINARY
to specify column j
as a VARBINARY column.
CREATE TABLE `test_binary` (
`id` INT(11) NOT NULL COMMENT "",
`j` VARBINARY NULL COMMENT ""
) ENGINE=OLAP
DUPLICATE KEY(`id`)
COMMENT "OLAP"
DISTRIBUTED BY HASH(`id`) BUCKETS 1
PROPERTIES (
"replication_num" = "3",
"storage_format" = "DEFAULT"
);
mysql> DESC test_binary;
+-------+-----------+------+-------+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------+-----------+------+-------+---------+-------+
| id | int | NO | true | NULL | |
| j | varbinary | YES | false | NULL | |
+-------+-----------+------+-------+---------+-------+
2 rows in set (0.01 sec)
Load data and store it as BINARY type
StarRocks supports the following ways to load data and store it as BINARY type.
Method 1: Use INSERT INTO to write data to a constant column of BINARY type (such as column
j
), where the constant column is prefixed withx''
.INSERT INTO test_binary (id, j) VALUES (1, x'abab'); INSERT INTO test_binary (id, j) VALUES (2, x'baba'); INSERT INTO test_binary (id, j) VALUES (3, x'010102'); INSERT INTO test_binary (id, j) VALUES (4, x'0000');
Method 2: Use the to_binary function to convert VARCHAR data to binary data.
INSERT INTO test_binary select 5, to_binary('abab', 'hex'); INSERT INTO test_binary select 6, to_binary('abab', 'base64'); INSERT INTO test_binary select 7, to_binary('abab', 'utf8');
Method 3: Use Broker Load to load a Parquet or ORC file and store the file as BINARY data. For more information, see Broker Load.
- For Parquet files, convert
parquet::Type::type::BYTE_ARRAY
toTYPE_VARBINARY
directly. - For ORC files, convert
orc::BINARY
toTYPE_VARBINARY
directly.
- For Parquet files, convert
Method 4: Use Stream Load to load a CSV file and store the file as
BINARY
data. For more information, see Load CSV data.- CSV file uses the hex format for binary data. Please ensure the input binary value is a valid hex value.
BINARY
type is only supported in CSV file. JSON file does not supportBINARY
type.
For example,
t1
is a table with a VARBINARY columnb
.CREATE TABLE `t1` ( `k` int(11) NOT NULL COMMENT "", `v` int(11) NOT NULL COMMENT "", `b` varbinary ) ENGINE = OLAP DUPLICATE KEY(`k`) PARTITION BY RANGE(`v`) ( PARTITION p1 VALUES [("-2147483648"), ("0")), PARTITION p2 VALUES [("0"), ("10")), PARTITION p3 VALUES [("10"), ("20"))) DISTRIBUTED BY HASH(`k`) BUCKETS 1 PROPERTIES ("replication_num" = "1"); -- csv file -- cat temp_data 0,0,ab -- Load CSV file using Stream Load. curl --location-trusted -u <username>:<password> -T temp_data -XPUT -H column_separator:, -H label:xx http://172.17.0.1:8131/api/test_mv/t1/_stream_load -- Query the loaded data. mysql> select * from t1; +------+------+------------+ | k | v | xx | +------+------+------------+ | 0 | 0 | 0xAB | +------+------+------------+ 1 rows in set (0.11 sec)
Query and process BINARY data
StarRocks supports querying and processing BINARY data, and supports the use of BINARY functions and operators. This example uses table test_binary
.
Note: If you add the --binary-as-hex
option When you access StarRocks from your MySQL client, binary data will be displayed using hex notation.
mysql> select * from test_binary;
+------+------------+
| id | j |
+------+------------+
| 1 | 0xABAB |
| 2 | 0xBABA |
| 3 | 0x010102 |
| 4 | 0x0000 |
| 5 | 0xABAB |
| 6 | 0xABAB |
| 7 | 0x61626162 |
+------+------------+
7 rows in set (0.08 sec)
Example 1: View binary data using the hex function.
mysql> select id, hex(j) from test_binary;
+------+----------+
| id | hex(j) |
+------+----------+
| 1 | ABAB |
| 2 | BABA |
| 3 | 010102 |
| 4 | 0000 |
| 5 | ABAB |
| 6 | ABAB |
| 7 | 61626162 |
+------+----------+
7 rows in set (0.02 sec)
Example 2: View binary data using the to_base64 function.
mysql> select id, to_base64(j) from test_binary;
+------+--------------+
| id | to_base64(j) |
+------+--------------+
| 1 | q6s= |
| 2 | uro= |
| 3 | AQEC |
| 4 | AAA= |
| 5 | q6s= |
| 6 | q6s= |
| 7 | YWJhYg== |
+------+--------------+
7 rows in set (0.01 sec)
Example 3: View binary data using the from_binary function.
mysql> select id, from_binary(j, 'hex') from test_binary;
+------+-----------------------+
| id | from_binary(j, 'hex') |
+------+-----------------------+
| 1 | ABAB |
| 2 | BABA |
| 3 | 010102 |
| 4 | 0000 |
| 5 | ABAB |
| 6 | ABAB |
| 7 | 61626162 |
+------+-----------------------+
7 rows in set (0.01 sec)