- 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
- 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 / 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 / IMPORT DATABASE
- INSERT
- PIVOT
- Profiling
- SELECT
- SET / RESET
- SET VARIABLE
- SUMMARIZE
- Transaction Management
- UNPIVOT
- UPDATE
- USE
- VACUUM
- LOAD / INSTALL
- Query Syntax
- SELECT
- FROM & 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 & 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
Set operations allow queries to be combined according to set operation semantics. Set operations refer to the UNION [ALL]
, INTERSECT [ALL]
and EXCEPT [ALL]
clauses. The vanilla variants use set semantics, i.e., they eliminate duplicates, while the variants with ALL
use bag semantics.
Traditional set operations unify queries by column position, and require the to-be-combined queries to have the same number of input columns. If the columns are not of the same type, casts may be added. The result will use the column names from the first query.
DuckDB also supports UNION [ALL] BY NAME
, which joins columns by name instead of by position. UNION BY NAME
does not require the inputs to have the same number of columns. NULL
values will be added in case of missing columns.
UNION
The UNION
clause can be used to combine rows from multiple queries. The queries are required to return the same number of columns. Implicit casting to one of the returned types is performed to combine columns of different types where necessary. If this is not possible, the UNION
clause throws an error.
Vanilla UNION
(Set Semantics)
The vanilla UNION
clause follows set semantics, therefore it performs duplicate elimination, i.e., only unique rows will be included in the result.
SELECT * FROM range(2) t1(x)
UNION
SELECT * FROM range(3) t2(x);
x |
---|
2 |
1 |
0 |
UNION ALL
(Bag Semantics)
UNION ALL
returns all rows of both queries following bag semantics, i.e., without duplicate elimination.
SELECT * FROM range(2) t1(x)
UNION ALL
SELECT * FROM range(3) t2(x);
x |
---|
0 |
1 |
0 |
1 |
2 |
UNION [ALL] BY NAME
The UNION [ALL] BY NAME
clause can be used to combine rows from different tables by name, instead of by position. UNION BY NAME
does not require both queries to have the same number of columns. Any columns that are only found in one of the queries are filled with NULL
values for the other query.
Take the following tables for example:
CREATE TABLE capitals (city VARCHAR, country VARCHAR);
INSERT INTO capitals VALUES
('Amsterdam', 'NL'),
('Berlin', 'Germany');
CREATE TABLE weather (city VARCHAR, degrees INTEGER, date DATE);
INSERT INTO weather VALUES
('Amsterdam', 10, '2022-10-14'),
('Seattle', 8, '2022-10-12');
SELECT * FROM capitals
UNION BY NAME
SELECT * FROM weather;
city | country | degrees | date |
---|---|---|---|
Seattle | NULL | 8 | 2022-10-12 |
Amsterdam | NL | NULL | NULL |
Berlin | Germany | NULL | NULL |
Amsterdam | NULL | 10 | 2022-10-14 |
UNION BY NAME
follows set semantics (therefore it performs duplicate elimination), whereas UNION ALL BY NAME
follows bag semantics.
INTERSECT
The INTERSECT
clause can be used to select all rows that occur in the result of both queries.
Vanilla INTERSECT
(Set Semantics)
Vanilla INTERSECT
performs duplicate elimination, so only unique rows are returned.
SELECT * FROM range(2) t1(x)
INTERSECT
SELECT * FROM range(6) t2(x);
x |
---|
0 |
1 |
INTERSECT ALL
(Bag Semantics)
INTERSECT ALL
follows bag semantics, so duplicates are returned.
SELECT unnest([5, 5, 6, 6, 6, 6, 7, 8]) AS x
INTERSECT ALL
SELECT unnest([5, 6, 6, 7, 7, 9]);
x |
---|
5 |
6 |
6 |
7 |
EXCEPT
The EXCEPT
clause can be used to select all rows that only occur in the left query.
Vanilla EXCEPT
(Set Semantics)
Vanilla EXCEPT
follows set semantics, therefore, it performs duplicate elimination, so only unique rows are returned.
SELECT * FROM range(5) t1(x)
EXCEPT
SELECT * FROM range(2) t2(x);
x |
---|
2 |
3 |
4 |
EXCEPT ALL
(Bag Semantics)
EXCEPT ALL
uses bag semantics:
SELECT unnest([5, 5, 6, 6, 6, 6, 7, 8]) AS x
EXCEPT ALL
SELECT unnest([5, 6, 6, 7, 7, 9]);
x |
---|
5 |
8 |
6 |
6 |