- Release Notes
- Get Started
- Clusters
- Cloud Settings
- Table Type
- Query Data Lakes
- Integration
- Query Acceleration
- Data Loading
- Concepts
- Batch load data from Amazon S3
- Batch load data from Azure cloud storage
- Load data from a local file system
- Load data from Confluent Cloud
- Load data from Amazon MSK
- Load data from Amazon Kinesis
- Data Unloading
- Data Backup
- Security
- Console Access Control
- Data Access Control
- Application keys
- Service accounts
- Use SSL connection
- Alarm
- Usage and Billing
- Organizations and Accounts
- Reference
- Amazon Web Services (AWS)
- Microsoft Azure
- SQL Reference
- Keywords
- ALL statements
- 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 RESOURCE GROUP
- ALTER SYSTEM
- CANCEL DECOMMISSION
- CREATE FILE
- CREATE RESOURCE GROUP
- DROP FILE
- DROP RESOURCE GROUP
- EXPLAIN
- INSTALL PLUGIN
- SET
- SHOW BACKENDS
- SHOW BROKER
- SHOW COMPUTE NODES
- SHOW FRONTENDS
- SHOW FULL COLUMNS
- SHOW INDEX
- SHOW PLUGINS
- SHOW PROCESSLIST
- SHOW RESOURCE GROUP
- SHOW TABLE STATUS
- SHOW FILE
- SHOW VARIABLES
- UNINSTALL PLUGIN
- DDL
- ALTER DATABASE
- ALTER MATERIALIZED VIEW
- ALTER TABLE
- ALTER VIEW
- 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 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 TABLE
- DROP VIEW
- DROP FUNCTION
- KILL ANALYZE
- RECOVER
- REFRESH EXTERNAL TABLE
- RESTORE
- SET CATALOG
- SHOW ANALYZE JOB
- SHOW ANALYZE STATUS
- SHOW META
- 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
- RESUME ROUTINE LOAD
- REFRESH MATERIALIZED VIEW
- SELECT
- SHOW ALTER
- 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 VIEW
- SHOW PARTITIONS
- SHOW REPOSITORIES
- SHOW RESTORE
- SHOW ROUTINE LOAD
- SHOW ROUTINE LOAD TASK
- SHOW SNAPSHOT
- SHOW TABLES
- SHOW TABLET
- SHOW TRANSACTION
- STOP ROUTINE LOAD
- STREAM LOAD
- SUBMIT TASK
- UPDATE
- Auxiliary Commands
- Data Types
- Keywords
- SQL Functions
- Function list
- Java UDFs
- Window functions
- Lambda expression
- Date Functions
- add_months
- adddate
- convert_tz
- current_date
- current_time
- current_timestamp
- date
- date_add
- date_diff
- date_format
- date_slice
- date_sub, subdate
- date_trunc
- datediff
- day
- dayofweek_iso
- dayname
- dayofmonth
- dayofweek
- dayofyear
- days_add
- days_diff
- days_sub
- from_days
- from_unixtime
- hour
- hours_add
- hours_diff
- hours_sub
- jodatime_format
- last_day
- makedate
- microseconds_add
- microseconds_sub
- minute
- minutes_add
- minutes_diff
- minutes_sub
- month
- monthname
- months_add
- months_diff
- months_sub
- next_day
- now
- previous_day
- quarter
- second
- seconds_add
- seconds_diff
- seconds_sub
- str_to_date
- str_to_jodatime
- str2date
- time_slice
- time_to_sec
- timediff
- timestamp
- timestampadd
- timestampdiff
- to_date
- to_days
- to_iso8601
- to_tera_date
- to_tera_timestamp
- unix_timestamp
- utc_timestamp
- week
- week_iso
- weekofyear
- weeks_add
- weeks_diff
- weeks_sub
- year
- years_add
- years_diff
- years_sub
- Aggregate Functions
- any_value
- approx_count_distinct
- array_agg
- avg
- bitmap
- bitmap_agg
- count
- count_if
- corr
- covar_pop
- covar_samp
- group_concat
- grouping
- grouping_id
- hll_empty
- hll_hash
- hll_raw_agg
- hll_union
- hll_union_agg
- max
- max_by
- min
- min_by
- 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
- Geographic 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
- substring_index
- starts_with
- strleft
- strright
- str_to_map
- substring
- trim
- ucase
- unhex
- upper
- url_decode
- url_encode
- Pattern Matching Functions
- JSON Functions
- Overview of JSON functions and operators
- JSON operators
- JSON constructor functions
- JSON query and processing functions
- Bit Functions
- Bitmap Functions
- Array Functions
- all_match
- any_match
- array_agg
- array_append
- array_avg
- array_concat
- array_contains
- array_contains_all
- array_cum_sum
- array_difference
- array_distinct
- array_filter
- array_generate
- 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
- Map Functions
- Binary Functions
- cast function
- hash function
- Cryptographic Functions
- Math Functions
- Pattern Matching Functions
- Percentile Functions
- Scalar Functions
- Struct Functions
- Table Functions
- Utility Functions
- AUTO_INCREMENT
- Generated columns
- System variables
- System limits
- Information Schema
- Overview
- be_bvars
- be_cloud_native_compactions
- be_compactions
- character_sets
- collations
- column_privileges
- columns
- engines
- events
- global_variables
- key_column_usage
- load_tracking_logs
- loads
- materialized_views
- partitions
- pipe_files
- pipes
- referential_constraints
- routines
- schema_privileges
- schemata
- session_variables
- statistics
- table_constraints
- table_privileges
- tables
- tables_config
- task_runs
- tasks
- triggers
- user_privileges
- views
- System Metadatabase
- API
- Overview
- Actions
- Clusters
- Create and Manage Clusters
- Query Clusters
- Identity and Access Management
- Organization and Account
- Usage and Billing
- Clusters
- Terraform Provider
- Run scripts
group_concat
Description
Concatenates non-null values from a group into a single string, with a sep
argument, which is ,
by default if not specified. This function can be used to concatenate values from multiple rows of a column into one string.
Syntax
VARCHAR GROUP_CONCAT([DISTINCT] expr [,expr ...]
[ORDER BY {unsigned_integer | col_name | expr}
[ASC | DESC] [,col_name ...]]
[SEPARATOR sep])
Parameters
expr
: the values to concatenate, with null values ignored. It must evaluate to VARCHAR. You can optionally specifyDISTINCT
to eliminate duplicate values from the output string. If you want to concatenate multipleexpr
directly, use concat or concat_ws to specify formats.- Items in ORDER BY can be unsigned integers (starting from 1), column names, or normal expressions. The results are sorted in ascending order by default. You can also explicitly specify the ASC keyword. If you want to sort results in descending order, add the DESC keyword to the name of the column you are sorting.
sep
: the optional separator used to concatenate non-null values from different rows. If it is not specified,,
(a comma) is used by default. To eliminate the separator, specify an empty string''
.
Return value
Returns a string value for each group and returns NULL if there are no non-NULL values.
You can limit the length of the string returned by group_concat by setting the session variable group_concat_max_len
, which defaults to 1024. Minimum value: 4. Unit: characters.
Example:
SET [GLOBAL | SESSION] group_concat_max_len = <value>;
Examples
Create a table
ss
which contains subject scores.CREATE TABLE `ss` ( `id` int(11) NULL COMMENT "", `name` varchar(255) NULL COMMENT "", `subject` varchar(255) NULL COMMENT "", `score` int(11) NULL COMMENT "" ) ENGINE=OLAP DUPLICATE KEY(`id`) DISTRIBUTED BY HASH(`id`) BUCKETS 4 PROPERTIES ( "replication_num" = "1" ); insert into ss values (1,"Tom","English",90); insert into ss values (1,"Tom","Math",80); insert into ss values (2,"Tom","English",NULL); insert into ss values (2,"Tom",NULL,NULL); insert into ss values (3,"May",NULL,NULL); insert into ss values (3,"Ti","English",98); insert into ss values (4,NULL,NULL,NULL); insert into ss values (NULL,"Ti","Phy",98); select * from ss order by id; +------+------+---------+-------+ | id | name | subject | score | +------+------+---------+-------+ | NULL | Ti | Phy | 98 | | 1 | Tom | English | 90 | | 1 | Tom | Math | 80 | | 2 | Tom | English | NULL | | 2 | Tom | NULL | NULL | | 3 | May | NULL | NULL | | 3 | Ti | English | 98 | | 4 | NULL | NULL | NULL | +------+------+---------+-------+
Use group_concat.
Example 1: Concatenate names into a string with the default separator and with null values ignored. Duplicate names are retained.
select group_concat(name) as res from ss;
+---------------------------+
| res |
+---------------------------+
| Tom,Tom,Ti,Tom,Tom,May,Ti |
+---------------------------+
Example 2: Concatenate names into a string, connected by the separator -
and with null values ignored. Duplicate names are retained.
select group_concat(name SEPARATOR '-') as res from ss;
+---------------------------+
| res |
+---------------------------+
| Ti-May-Ti-Tom-Tom-Tom-Tom |
+---------------------------+
Example 3: Concatenate distinct names into a string with the default separator and with null values ignored. Duplicate names are removed.
select group_concat(distinct name) as res from ss;
+---------------------------+
| res |
+---------------------------+
| Ti,May,Tom |
+---------------------------+
Example 4: Concatenate the name-subject strings of the same ID in ascending order of score
. For example, TomMath
and TomEnglish
share ID 1 and they are concatenated with a comma in ascending order of score
.
select id, group_concat(distinct name,subject order by score) as res from ss group by id order by id;
+------+--------------------+
| id | res |
+------+--------------------+
| NULL | TiPhy |
| 1 | TomMath,TomEnglish |
| 2 | TomEnglish |
| 3 | TiEnglish |
| 4 | NULL |
+------+--------------------+
Example 5: group_concat is nested with concat(), which is used to combine name
, -
, and subject
as a string. The strings in the same row are sorted in ascending order of score
.
select id, group_concat(distinct concat(name,'-',subject) order by score) as res from ss group by id order by id;
+------+----------------------+
| id | res |
+------+----------------------+
| NULL | Ti-Phy |
| 1 | Tom-Math,Tom-English |
| 2 | Tom-English |
| 3 | Ti-English |
| 4 | NULL |
+------+----------------------+
Example 6: No matching result is found and NULL is returned.
select group_concat(distinct name) as res from ss where id < 0;
+------+
| res |
+------+
| NULL |
+------+
Example 7: Limit the length of the returned string to six characters.
set group_concat_max_len = 6;
select id, group_concat(distinct name,subject order by score) as res from ss group by id order by id;
+------+--------+
| id | res |
+------+--------+
| NULL | TiPhy |
| 1 | TomMat |
| 2 | NULL |
| 3 | TiEngl |
| 4 | NULL |
+------+--------+
keyword
GROUP_CONCAT,CONCAT,ARRAY_AGG