- 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 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
ORDER BY
is an output modifier. Logically it is applied near the very end of the query (just prior to LIMIT
or OFFSET
, if present).
The ORDER BY
clause sorts the rows on the sorting criteria in either ascending or descending order.
In addition, every order clause can specify whether NULL
values should be moved to the beginning or to the end.
The ORDER BY
clause may contain one or more expressions, separated by commas.
An error will be thrown if no expressions are included, since the ORDER BY
clause should be removed in that situation.
The expressions may begin with either an arbitrary scalar expression (which could be a column name), a column position number (Ex: 1
. Note that it is 1-indexed), or the keyword ALL
.
Each expression can optionally be followed by an order modifier (ASC
or DESC
, default is ASC
), and/or a NULL
order modifier (NULLS FIRST
or NULLS LAST
, default is NULLS LAST
).
ORDER BY ALL
The ALL
keyword indicates that the output should be sorted by every column in order from left to right.
The direction of this sort may be modified using either ORDER BY ALL ASC
or ORDER BY ALL DESC
and/or NULLS FIRST
or NULLS LAST
.
Note that ALL
may not be used in combination with other expressions in the ORDER BY
clause – it must be by itself.
See examples below.
NULL Order Modifier
By default if no modifiers are provided, DuckDB sorts ASC NULLS LAST
, i.e., the values are sorted in ascending order and null values are placed last.
This is identical to the default sort order of PostgreSQL. The default sort order can be changed with the following configuration options.
Using
ASC NULLS LAST
as the default sorting order was a breaking change in version 0.8.0. Prior to 0.8.0, DuckDB sorted usingASC NULLS FIRST
.
Change the default null sorting order to either NULLS_FIRST
, NULLS_LAST
, NULLS_FIRST_ON_ASC_LAST_ON_DESC
or NULLS_LAST_ON_ASC_FIRST_ON_DESC
:
SET default_null_order = 'NULLS_FIRST';
Change the default sorting order to either DESC
or ASC
:
SET default_order = 'DESC';
Collations
Text is sorted using the binary comparison collation by default, which means values are sorted on their binary UTF-8 values. While this works well for ASCII text (e.g., for English language data), the sorting order can be incorrect for other languages. For this purpose, DuckDB provides collations. For more information on collations, see the Collation page.
Examples
All examples use this example table:
CREATE OR REPLACE TABLE addresses AS
SELECT '123 Quack Blvd' AS address, 'DuckTown' AS city, '11111' AS zip
UNION ALL
SELECT '111 Duck Duck Goose Ln', 'DuckTown', '11111'
UNION ALL
SELECT '111 Duck Duck Goose Ln', 'Duck Town', '11111'
UNION ALL
SELECT '111 Duck Duck Goose Ln', 'Duck Town', '11111-0001';
Select the addresses, ordered by city name using the default null order and default order:
SELECT *
FROM addresses
ORDER BY city;
Select the addresses, ordered by city name in descending order with nulls at the end:
SELECT *
FROM addresses
ORDER BY city DESC NULLS LAST;
Order by city and then by zip code, both using the default orderings:
SELECT *
FROM addresses
ORDER BY city, zip;
Order by city using German collation rules:
SELECT *
FROM addresses
ORDER BY city COLLATE DE;
ORDER BY ALL
Examples
Order from left to right (by address, then by city, then by zip) in ascending order:
SELECT *
FROM addresses
ORDER BY ALL;
address | city | zip |
---|---|---|
111 Duck Duck Goose Ln | Duck Town | 11111 |
111 Duck Duck Goose Ln | Duck Town | 11111-0001 |
111 Duck Duck Goose Ln | DuckTown | 11111 |
123 Quack Blvd | DuckTown | 11111 |
Order from left to right (by address, then by city, then by zip) in descending order:
SELECT *
FROM addresses
ORDER BY ALL DESC;
address | city | zip |
---|---|---|
123 Quack Blvd | DuckTown | 11111 |
111 Duck Duck Goose Ln | DuckTown | 11111 |
111 Duck Duck Goose Ln | Duck Town | 11111-0001 |
111 Duck Duck Goose Ln | Duck Town | 11111 |