- 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
MAP
s are similar to STRUCT
s in that they are an ordered list of “entries” where a key maps to a value. However, MAP
s do not need to have the same keys present for each row, and thus are suitable for other use cases. MAP
s are useful when the schema is unknown beforehand or when the schema varies per row; their flexibility is a key differentiator.
MAP
s must have a single type for all keys, and a single type for all values. Keys and values can be any type, and the type of the keys does not need to match the type of the values (e.g., a MAP
of VARCHAR
to INT
is valid). MAP
s may not have duplicate keys. MAP
s return an empty list if a key is not found rather than throwing an error as structs do.
In contrast, STRUCT
s must have string keys, but each key may have a value of a different type. See the data types overview for a comparison between nested data types.
To construct a MAP
, use the bracket syntax preceded by the MAP
keyword.
Creating Maps
A map with VARCHAR
keys and INTEGER
values. This returns {key1=10, key2=20, key3=30}
:
SELECT MAP {'key1': 10, 'key2': 20, 'key3': 30};
Alternatively use the map_from_entries function. This returns {key1=10, key2=20, key3=30}
:
SELECT map_from_entries([('key1', 10), ('key2', 20), ('key3', 30)]);
A map can be also created using two lists: keys and values. This returns {key1=10, key2=20, key3=30}
:
SELECT MAP(['key1', 'key2', 'key3'], [10, 20, 30]);
A map can also use INTEGER keys and NUMERIC values. This returns {1=42.001, 5=-32.100}
:
SELECT MAP {1: 42.001, 5: -32.1};
Keys and/or values can also be nested types. This returns {[a, b]=[1.1, 2.2], [c, d]=[3.3, 4.4]}
:
SELECT MAP {['a', 'b']: [1.1, 2.2], ['c', 'd']: [3.3, 4.4]};
Create a table with a map column that has INTEGER keys and DOUBLE values:
CREATE TABLE tbl (col MAP(INTEGER, DOUBLE));
Retrieving from Maps
MAP
s use bracket notation for retrieving values. Selecting from a MAP
returns a LIST
rather than an individual value, with an empty LIST
meaning that the key was not found.
Use bracket notation to retrieve a list containing the value at a key's location. This returns [5]
. Note that the expression in bracket notation must match the type of the map's key:
SELECT MAP {'key1': 5, 'key2': 43}['key1'];
To retrieve the underlying value, use list selection syntax to grab the first element. This returns 5
:
SELECT MAP {'key1': 5, 'key2': 43}['key1'][1];
If the element is not in the map, an empty list will be returned. This returns []
. Note that the expression in bracket notation must match the type of the map's key else an error is returned:
SELECT MAP {'key1': 5, 'key2': 43}['key3'];
The element_at function can also be used to retrieve a map value. This returns [5]
:
SELECT element_at(MAP {'key1': 5, 'key2': 43}, 'key1');
Comparison Operators
Nested types can be compared using all the comparison operators.
These comparisons can be used in logical expressions
for both WHERE
and HAVING
clauses, as well as for creating Boolean values.
The ordering is defined positionally in the same way that words can be ordered in a dictionary.
NULL
values compare greater than all other values and are considered equal to each other.
At the top level, NULL
nested values obey standard SQL NULL
comparison rules:
comparing a NULL
nested value to a non-NULL
nested value produces a NULL
result.
Comparing nested value members, however, uses the internal nested value rules for NULL
s,
and a NULL
nested value member will compare above a non-NULL
nested value member.
Functions
See Map Functions.