- 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
- ADBC
- C
- Overview
- Startup
- Configuration
- Query
- Data Chunks
- Vectors
- Values
- Types
- Prepared Statements
- Appender
- Table Functions
- Replacement Scans
- API Reference
- C++
- CLI
- Overview
- Arguments
- Dot Commands
- Output Formats
- Editing
- Safe Mode
- Autocomplete
- Syntax Highlighting
- Known Issues
- Dart
- Go
- Java (JDBC)
- Julia
- Node.js (Deprecated)
- Node.js (Neo)
- ODBC
- PHP
- 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
- 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
- LOAD / INSTALL
- PIVOT
- Profiling
- SELECT
- SET / RESET
- SET VARIABLE
- SUMMARIZE
- Transaction Management
- UNPIVOT
- UPDATE
- USE
- VACUUM
- 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 Expression
- Casting
- Collations
- Comparisons
- IN Operator
- Logical Operators
- Star Expression
- Subqueries
- TRY
- 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
- Overview
- Indexing
- Friendly SQL
- Keywords and Identifiers
- Order Preservation
- PostgreSQL Compatibility
- SQL Quirks
- Samples
- Configuration
- Extensions
- Overview
- Installing Extensions
- Advanced Installation Methods
- Distributing Extensions
- Versioning of Extensions
- Troubleshooting of Extensions
- Core Extensions
- Overview
- AutoComplete
- Avro
- AWS
- Azure
- Delta
- DuckLake
- Encodings
- Excel
- Full Text Search
- httpfs (HTTP and S3)
- Iceberg
- Overview
- Iceberg REST Catalogs
- Amazon S3 Tables
- Amazon SageMaker Lakehouse (AWS Glue)
- Troubleshooting
- ICU
- inet
- jemalloc
- MySQL
- PostgreSQL
- Spatial
- SQLite
- TPC-DS
- TPC-H
- UI
- 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
- File Access with the file: Protocol
- 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
- Fastly Object Storage Import
- 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
- Working with Huge Databases
- Python
- Installation
- Executing SQL
- Jupyter Notebooks
- marimo 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
- Creating Synthetic Data
- Dutch Railway Datasets
- Sharing Macros
- Analyzing a Git Repository
- Importing Duckbox Tables
- Copying an In-Memory Database to a File
- Troubleshooting
- Glossary of Terms
- Browsing Offline
- Operations Manual
- Overview
- DuckDB's Footprint
- Logging
- Securing DuckDB
- Non-Deterministic Behavior
- Limits
- Development
- DuckDB Repositories
- Profiling
- Building DuckDB
- Overview
- Build Configuration
- Building Extensions
- Android
- Linux
- macOS
- Raspberry Pi
- Windows
- Python
- R
- Troubleshooting
- Unofficial and Unsupported Platforms
- Benchmark Suite
- Testing
- Internals
- Sitemap
- Live Demo
Timestamp with Time Zone Promotion Casts
Working with time zones in SQL can be quite confusing at times. For example, when filtering to a date range, one might try the following query:
SET timezone = 'America/Los_Angeles';
CREATE TABLE times AS
FROM range('2025-08-30'::TIMESTAMPTZ, '2025-08-31'::TIMESTAMPTZ, INTERVAL 1 HOUR) tbl(t);
FROM times WHERE t <= '2025-08-30';
┌──────────────────────────┐
│ t │
│ timestamp with time zone │
├──────────────────────────┤
│ 2025-08-30 00:00:00-07 │
└──────────────────────────┘
But if you change to another time zone, the results of the query change:
SET timezone = 'HST';
FROM times WHERE t <= '2025-08-30';
┌──────────────────────────┐
│ t │
│ timestamp with time zone │
├──────────────────────────┤
│ 2025-08-29 21:00:00-10 │
│ 2025-08-29 22:00:00-10 │
│ 2025-08-29 23:00:00-10 │
│ 2025-08-30 00:00:00-10 │
└──────────────────────────┘
Or worse:
SET timezone = 'America/New_York';
FROM times WHERE t <= '2025-08-30';
┌──────────────────────────┐
│ t │
│ timestamp with time zone │
├──────────────────────────┤
│ 0 rows │
└──────────────────────────┘
These confusing results are due to the SQL casting rules from DATE
to TIMESTAMP WITH TIME ZONE
.
This cast is required to promote the date to midnight in the current time zone.
In general, unless you need to use the current time zone for display (or
other temporal binning operations)
you should use plain TIMESTAMP
s for temporal data.
This will avoid confusing issues such as this, and the arithmetic operations are generally faster.
Time Zone Performance
DuckDB uses the International Components for Unicode time library for time zone support. This library has a number of advantages, including support for daylight savings time past 2037. (Note: Pandas gives incorrect results past that year).
The downside of using ICU is that it is not highly performant. One workaround for this is to create a calendar table for the timestamps being modeled. For example, if the application is modeling electrical supply and demand out to 2100 at hourly resolution, one can create the calendar table like so:
SET timezone = 'Europe/Netherlands';
CREATE OR REPLACE TABLE hourly AS
SELECT
ts,
year::SMALLINT AS year,
month::TINYINT AS month,
day::TINYINT AS day,
hour::TINYINT AS hour,
FROM (
SELECT ts, unnest(date_part(['year', 'month', 'day', 'hour',], ts))
FROM generate_series(
'2020-01-01'::DATE::TIMESTAMPTZ,
'2100-01-01'::DATE::TIMESTAMPTZ,
INTERVAL 1 HOUR) tbl(ts)
) parts;
You can then join this ~700K row table against any timestamp column
to quickly obtain the temporal bin values for the time zone in question.
The inner casts are not required, but result in a smaller table
because date_part
returns 64 bit integers for all parts.
Notice that we can extract all of the parts with a single call to date_part
.
This part list version of the function is faster than extracting the parts one by one
because the underlying binning computation computes all parts,
so picking out the ones in the list is avoids duplicate calls to the slow ICU function.
Also notice that we are leveraging the DATE
cast rules from the previous section
to bound the calendar to the model domain.
Half Open Intervals
Another subtle problem in using SQL for temporal analytics is the BETWEEN
operator.
Temporal analytics almost always uses
half-open binning intervals
to avoid overlaps at the ends.
Unfortunately, the BETWEEN
operator is a closed-closed interval:
x BETWEEN begin AND end
-- expands to
begin <= x AND x <= end
-- not
begin <= x AND x < end
To avoid this problem, make sure you are explicit about comparison boundaries instead of using BETWEEN
.