- Installation
- Documentation
- Getting Started
- Connect
- Data Import
- Overview
- Data Sources
- CSV Files
- JSON Files
- Overview
- Creating JSON
- Loading JSON
- Writing JSON
- JSON Type
- JSON Functions
- Format Settings
- Installing and Loading
- SQL to / from JSON
- Caveats
- Multiple Files
- Parquet Files
- Partitioning
- Appender
- INSERT Statements
- Client APIs
- Overview
- C
- Overview
- Startup
- Configuration
- Query
- Data Chunks
- Vectors
- Values
- Types
- Prepared Statements
- Appender
- Table Functions
- Replacement Scans
- API Reference
- C++
- CLI
- Dart
- Go
- Java
- Julia
- Node.js
- Python
- Overview
- Data Ingestion
- Conversion between DuckDB and Python
- DB API
- Relational API
- Function API
- Types API
- Expression API
- Spark API
- API Reference
- Known Python Issues
- R
- Rust
- Swift
- Wasm
- ADBC
- ODBC
- SQL
- Introduction
- Statements
- Overview
- ANALYZE
- ALTER TABLE
- ALTER VIEW
- ATTACH and DETACH
- CALL
- CHECKPOINT
- COMMENT ON
- COPY
- CREATE INDEX
- CREATE MACRO
- CREATE SCHEMA
- CREATE SECRET
- CREATE SEQUENCE
- CREATE TABLE
- CREATE VIEW
- CREATE TYPE
- DELETE
- DESCRIBE
- DROP
- EXPORT and IMPORT DATABASE
- INSERT
- PIVOT
- Profiling
- SELECT
- SET / RESET
- SET VARIABLE
- SUMMARIZE
- Transaction Management
- UNPIVOT
- UPDATE
- USE
- VACUUM
- LOAD / INSTALL
- Query Syntax
- SELECT
- FROM and JOIN
- WHERE
- GROUP BY
- GROUPING SETS
- HAVING
- ORDER BY
- LIMIT and OFFSET
- SAMPLE
- Unnesting
- WITH
- WINDOW
- QUALIFY
- VALUES
- FILTER
- Set Operations
- Prepared Statements
- Data Types
- Overview
- Array
- Bitstring
- Blob
- Boolean
- Date
- Enum
- Interval
- List
- Literal Types
- Map
- NULL Values
- Numeric
- Struct
- Text
- Time
- Timestamp
- Time Zones
- Union
- Typecasting
- Expressions
- Overview
- CASE Statement
- Casting
- Collations
- Comparisons
- IN Operator
- Logical Operators
- Star Expression
- Subqueries
- Functions
- Overview
- Aggregate Functions
- Array Functions
- Bitstring Functions
- Blob Functions
- Date Format Functions
- Date Functions
- Date Part Functions
- Enum Functions
- Interval Functions
- Lambda Functions
- List Functions
- Map Functions
- Nested Functions
- Numeric Functions
- Pattern Matching
- Regular Expressions
- Struct Functions
- Text Functions
- Time Functions
- Timestamp Functions
- Timestamp with Time Zone Functions
- Union Functions
- Utility Functions
- Window Functions
- Constraints
- Indexes
- Meta Queries
- DuckDB's SQL Dialect
- Samples
- Configuration
- Extensions
- Overview
- Core Extensions
- Community Extensions
- Working with Extensions
- Versioning of Extensions
- Arrow
- AutoComplete
- AWS
- Azure
- Delta
- Excel
- Full Text Search
- httpfs (HTTP and S3)
- Iceberg
- ICU
- inet
- jemalloc
- MySQL
- PostgreSQL
- Spatial
- SQLite
- Substrait
- TPC-DS
- TPC-H
- VSS
- Guides
- Overview
- Data Viewers
- Database Integration
- File Formats
- Overview
- CSV Import
- CSV Export
- Directly Reading Files
- Excel Import
- Excel Export
- JSON Import
- JSON Export
- Parquet Import
- Parquet Export
- Querying Parquet Files
- Network and Cloud Storage
- Overview
- HTTP Parquet Import
- S3 Parquet Import
- S3 Parquet Export
- S3 Iceberg Import
- S3 Express One
- GCS Import
- Cloudflare R2 Import
- DuckDB over HTTPS / S3
- Meta Queries
- Describe Table
- EXPLAIN: Inspect Query Plans
- EXPLAIN ANALYZE: Profile Queries
- List Tables
- Summarize
- DuckDB Environment
- ODBC
- Performance
- Overview
- Environment
- Import
- Schema
- Indexing
- Join Operations
- File Formats
- How to Tune Workloads
- My Workload Is Slow
- Benchmarks
- Python
- Installation
- Executing SQL
- Jupyter Notebooks
- SQL on Pandas
- Import from Pandas
- Export to Pandas
- Import from Numpy
- Export to Numpy
- SQL on Arrow
- Import from Arrow
- Export to Arrow
- Relational API on Pandas
- Multiple Python Threads
- Integration with Ibis
- Integration with Polars
- Using fsspec Filesystems
- SQL Editors
- SQL Features
- Snippets
- Glossary of Terms
- Browse Offline
- Operations Manual
- Overview
- Limits
- Non-Deterministic Behavior
- Embedding DuckDB
- DuckDB's Footprint
- Securing DuckDB
- Development
- DuckDB Repositories
- Testing
- Overview
- sqllogictest Introduction
- Writing Tests
- Debugging
- Result Verification
- Persistent Testing
- Loops
- Multiple Connections
- Catch
- Profiling
- Release Calendar
- Building
- Benchmark Suite
- Internals
- Sitemap
- Why DuckDB
- Media
- FAQ
- Code of Conduct
- Live Demo
A LIST
column encodes lists of values. Fields in the column can have values with different lengths, but they must all have the same underlying type. LIST
s are typically used to store arrays of numbers, but can contain any uniform data type, including other LIST
s and STRUCT
s.
LIST
s are similar to PostgreSQL's ARRAY
type. DuckDB uses the LIST
terminology, but some array_
functions are provided for PostgreSQL compatibility.
See the data types overview for a comparison between nested data types.
For storing fixed-length lists, DuckDB uses the
ARRAY
type.
Creating Lists
Lists can be created using the list_value(expr, ...)
function or the equivalent bracket notation [expr, ...]
. The expressions can be constants or arbitrary expressions. To create a list from a table column, use the list
aggregate function.
List of integers:
SELECT [1, 2, 3];
List of strings with a NULL
value:
SELECT ['duck', 'goose', NULL, 'heron'];
List of lists with NULL
values:
SELECT [['duck', 'goose', 'heron'], NULL, ['frog', 'toad'], []];
Create a list with the list_value function:
SELECT list_value(1, 2, 3);
Create a table with an INTEGER
list column and a VARCHAR
list column:
CREATE TABLE list_table (int_list INTEGER[], varchar_list VARCHAR[]);
Retrieving from Lists
Retrieving one or more values from a list can be accomplished using brackets and slicing notation, or through list functions like list_extract
. Multiple equivalent functions are provided as aliases for compatibility with systems that refer to lists as arrays. For example, the function array_slice
.
We wrap the list creation in parenthesis so that it happens first. This is only needed in our basic examples here, not when working with a list column. For example, this can't be parsed:
SELECT ['a', 'b', 'c'][1]
.
Example | Result |
---|---|
SELECT (['a', 'b', 'c'])[3] | 'c' |
SELECT (['a', 'b', 'c'])[-1] | 'c' |
SELECT (['a', 'b', 'c'])[2 + 1] | 'c' |
SELECT list_extract(['a', 'b', 'c'], 3) | 'c' |
SELECT (['a', 'b', 'c'])[1:2] | ['a', 'b'] |
SELECT (['a', 'b', 'c'])[:2] | ['a', 'b'] |
SELECT (['a', 'b', 'c'])[-2:] | ['b', 'c'] |
SELECT list_slice(['a', 'b', 'c'], 2, 3) | ['b', 'c'] |
Comparison and Ordering
The LIST
type can be compared using all the comparison operators.
These comparisons can be used in logical expressions
such as WHERE
and HAVING
clauses, and return BOOLEAN
values.
The LIST
ordering is defined positionally using the following rules, where min_len = min(len(l1), len(l2))
.
- Equality.
l1
andl2
are equal, if for eachi
in[1, min_len]
:l1[i] = l2[i]
. - Less Than. For the first index
i
in[1, min_len]
wherel1[i] != l2[i]
: Ifl1[i] < l2[i]
,l1
is less thanl2
.
NULL
values are compared following PostgreSQL's semantics.
Lower nesting levels are used for tie-breaking.
Here are some queries returning true
for the comparison.
SELECT [1, 2] < [1, 3] AS result;
SELECT [[1], [2, 4, 5]] < [[2]] AS result;
SELECT [ ] < [1] AS result;
These queries return false
.
SELECT [ ] < [ ] AS result;
SELECT [1, 2] < [1] AS result;
These queries return NULL
.
SELECT [1, 2] < [1, NULL, 4] AS result;
Updating Lists
Updates on lists are internally represented as an insert and a delete operation. Therefore, updating list values may lead to a duplicate key error on primary/unique keys. See the following example:
CREATE TABLE tbl (id INTEGER PRIMARY KEY, lst INTEGER[], comment VARCHAR);
INSERT INTO tbl VALUES (1, [12, 34], 'asd');
UPDATE tbl SET lst = [56, 78] WHERE id = 1;
Constraint Error: Duplicate key "id: 1" violates primary key constraint.
If this is an unexpected constraint violation please double check with the known index limitations section in our documentation (https://duckdb.org/docs/sql/indexes).
Functions
See List Functions.