From cdd70922ddc7291647e7a811cc7b6a923a2b241d Mon Sep 17 00:00:00 2001 From: BohuTANG Date: Tue, 11 Nov 2025 21:45:48 +0800 Subject: [PATCH] docs: add convert_timezone reference --- .../05-datetime-functions/convert-timezone.md | 93 +++++++++++++++++++ .../05-datetime-functions/index.md | 93 ++++++++++--------- .../05-datetime-functions/convert-timezone.md | 93 +++++++++++++++++++ .../05-datetime-functions/index.md | 1 + 4 files changed, 234 insertions(+), 46 deletions(-) create mode 100644 docs/cn/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md create mode 100644 docs/en/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md diff --git a/docs/cn/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md b/docs/cn/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md new file mode 100644 index 0000000000..5f6a9a0730 --- /dev/null +++ b/docs/cn/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md @@ -0,0 +1,93 @@ +--- +title: CONVERT_TIMEZONE +--- +import FunctionDescription from '@site/src/components/FunctionDescription'; + + + +`CONVERT_TIMEZONE()` 用于将时间戳从当前会话时区(默认 `UTC`)转换为第一个参数指定的目标时区。目标时区必须是有效的 [IANA 时区名称](https://docs.rs/chrono-tz/latest/chrono_tz/enum.Tz.html)。 + +## 语法 + +```sql +CONVERT_TIMEZONE(, ) +``` + +| 参数 | 说明 | +|------|------| +| `` | 区分大小写的时区名称,例如 `'America/Los_Angeles'` 或 `'UTC'`。 | +| `` | 可解析为 TIMESTAMP 的表达式,按照当前会话时区进行解释。 | + +## 返回类型 + +返回目标时区下等价时刻的 TIMESTAMP。 + +## 行为说明 + +- 源时区始终等于当前会话时区(默认 `UTC`)。如果存储的数据使用其他时区,请先在会话或连接层面做好设置。 +- 无效的时区名称会报错;任一参数为 `NULL` 时返回 `NULL`。 +- 夏令时缺口可能导致部分时间戳无效,可在会话或租户级别开启 `enable_dst_hour_fix = 1` 让 Databend 自动调整。 + +## 示例 + +### 默认 UTC 会话下的单次转换 + +```sql +SELECT CONVERT_TIMEZONE('America/Los_Angeles', '2024-11-01 11:36:10'); +``` + +``` +┌──────────────────────────────────────────────────────┐ +│ convert_timezone('America/Los_Angeles', '2024-11-01… │ +├──────────────────────────────────────────────────────┤ +│ 2024-11-01 04:36:10.000000 │ +└──────────────────────────────────────────────────────┘ +``` + +### 按用户偏好转换多行数据 + +```sql +SELECT + user_tz, + event_time, + CONVERT_TIMEZONE(user_tz, event_time) AS local_time +FROM ( + VALUES + ('America/Los_Angeles', '2024-10-31 22:21:15'::TIMESTAMP), + ('Asia/Shanghai', '2024-10-31 22:21:15'::TIMESTAMP), + (NULL, '2024-10-31 22:21:15'::TIMESTAMP) +) AS v(user_tz, event_time) +ORDER BY user_tz NULLS LAST; +``` + +``` +┌──────────────────────┬──────────────────────────────┬──────────────────────────────┐ +│ user_tz │ event_time │ local_time │ +├──────────────────────┼──────────────────────────────┼──────────────────────────────┤ +│ America/Los_Angeles │ 2024-10-31 22:21:15.000000 │ 2024-10-31 15:21:15.000000 │ +│ Asia/Shanghai │ 2024-10-31 22:21:15.000000 │ 2024-11-01 06:21:15.000000 │ +│ NULL │ 2024-10-31 22:21:15.000000 │ NULL │ +└──────────────────────┴──────────────────────────────┴──────────────────────────────┘ +``` + +### 处理落在夏令时缺口内的时间戳 + +本示例的会话已配置为 Asia/Shanghai 并开启 `enable_dst_hour_fix = 1`。由于 1947 年 4 月 15 日 00:00:00 在该时区并不存在(时钟向前跳一小时),Databend 会先调整后再返回其对应的 UTC 时间。 + +```sql +SELECT CONVERT_TIMEZONE('UTC', '1947-04-15 00:00:00'); +``` + +``` +┌──────────────────────────────────────────────┐ +│ convert_timezone('UTC', '1947-04-15 00:00:00')│ +├──────────────────────────────────────────────┤ +│ 1947-04-14 15:00:00.000000 │ +└──────────────────────────────────────────────┘ +``` + +## 另请参阅 + +- [TIMEZONE](timezone.md) +- [TO_TIMESTAMP_TZ](to-timestamp-tz.md) +- [TO_TIMESTAMP](to-timestamp.md) diff --git a/docs/cn/sql-reference/20-sql-functions/05-datetime-functions/index.md b/docs/cn/sql-reference/20-sql-functions/05-datetime-functions/index.md index 636b7646b5..5959df8c85 100644 --- a/docs/cn/sql-reference/20-sql-functions/05-datetime-functions/index.md +++ b/docs/cn/sql-reference/20-sql-functions/05-datetime-functions/index.md @@ -2,87 +2,88 @@ title: 日期与时间函数 --- -本页面按功能分类,全面梳理 Databend 中的日期与时间函数,便于快速查阅。 +本文按功能分类整理了 Databend 中的所有日期时间函数,方便您快速查找使用。 ## 当前日期与时间函数 | 函数 | 描述 | 示例 | |-------------------------------------------|--------------------------|------------------------------------------------------| -| [NOW](now.md) | 返回当前日期和时间 | `NOW()` → `2024-06-04 17:42:31.123456` | -| [CURRENT_TIMESTAMP](current-timestamp.md) | 返回当前日期和时间 | `CURRENT_TIMESTAMP()` → `2024-06-04 17:42:31.123456` | +| [NOW](now.md) | 获取当前日期和时间 | `NOW()` → `2024-06-04 17:42:31.123456` | +| [CURRENT_TIMESTAMP](current-timestamp.md) | 获取当前日期和时间 | `CURRENT_TIMESTAMP()` → `2024-06-04 17:42:31.123456` | | [TODAY](today.md) | 返回当前日期 | `TODAY()` → `2024-06-04` | -| [TOMORROW](tomorrow.md) | 返回明天的日期 | `TOMORROW()` → `2024-06-05` | -| [YESTERDAY](yesterday.md) | 返回昨天的日期 | `YESTERDAY()` → `2024-06-03` | +| [TOMORROW](tomorrow.md) | 获取明天的日期 | `TOMORROW()` → `2024-06-05` | +| [YESTERDAY](yesterday.md) | 获取昨天的日期 | `YESTERDAY()` → `2024-06-03` | ## 日期与时间提取函数 | 函数 | 描述 | 示例 | |-------------------------------------------|--------------------------|------------------------------------------| -| [YEAR](year.md) | 提取日期中的年份 | `YEAR('2024-06-04')` → `2024` | -| [MONTH](month.md) | 提取日期中的月份 | `MONTH('2024-06-04')` → `6` | -| [DAY](day.md) | 提取日期中的日 | `DAY('2024-06-04')` → `4` | -| [QUARTER](quarter.md) | 提取日期中的季度 | `QUARTER('2024-06-04')` → `2` | -| [WEEK](week.md) / [WEEKOFYEAR](weekofyear.md) | 提取日期中的周数 | `WEEK('2024-06-04')` → `23` | +| [YEAR](year.md) | 提取年份 | `YEAR('2024-06-04')` → `2024` | +| [MONTH](month.md) | 提取月份 | `MONTH('2024-06-04')` → `6` | +| [DAY](day.md) | 提取日期 | `DAY('2024-06-04')` → `4` | +| [QUARTER](quarter.md) | 提取季度 | `QUARTER('2024-06-04')` → `2` | +| [WEEK](week.md) / [WEEKOFYEAR](weekofyear.md) | 提取周数 | `WEEK('2024-06-04')` → `23` | | [EXTRACT](extract.md) | 提取日期的指定部分 | `EXTRACT(MONTH FROM '2024-06-04')` → `6` | | [DATE_PART](date-part.md) | 提取日期的指定部分 | `DATE_PART('month', '2024-06-04')` → `6` | -| [YEARWEEK](yearweek.md) | 返回年份和周数 | `YEARWEEK('2024-06-04')` → `202423` | -| [MILLENNIUM](millennium.md) | 返回日期所在的千年 | `MILLENNIUM('2024-06-04')` → `3` | +| [YEARWEEK](yearweek.md) | 获取年份和周数 | `YEARWEEK('2024-06-04')` → `202423` | +| [MILLENNIUM](millennium.md) | 获取日期所在的千年 | `MILLENNIUM('2024-06-04')` → `3` | ## 日期与时间转换函数 | 函数 | 描述 | 示例 | |-------------------------------------------|------------------------------------|---------------------------------------------------------------| -| [DATE](date.md) | 将值转换为 DATE 类型 | `DATE('2024-06-04')` → `2024-06-04` | -| [TO_DATE](to-date.md) | 将字符串转换为 DATE 类型 | `TO_DATE('2024-06-04')` → `2024-06-04` | -| [TO_DATETIME](to-datetime.md) | 将字符串转换为 DATETIME 类型 | `TO_DATETIME('2024-06-04 12:30:45')` → `2024-06-04 12:30:45` | -| [TO_TIMESTAMP](to-timestamp.md) | 将字符串转换为 TIMESTAMP 类型 | `TO_TIMESTAMP('2024-06-04 12:30:45')` → `2024-06-04 12:30:45` | -| [TO_UNIX_TIMESTAMP](to-unix-timestamp.md) | 将日期转换为 Unix 时间戳 | `TO_UNIX_TIMESTAMP('2024-06-04')` → `1717516800` | -| [TO_YYYYMM](to-yyyymm.md) | 将日期格式化为 YYYYMM | `TO_YYYYMM('2024-06-04')` → `202406` | -| [TO_YYYYMMDD](to-yyyymmdd.md) | 将日期格式化为 YYYYMMDD | `TO_YYYYMMDD('2024-06-04')` → `20240604` | -| [TO_YYYYMMDDHH](to-yyyymmddhh.md) | 将日期格式化为 YYYYMMDDHH | `TO_YYYYMMDDHH('2024-06-04 12:30:45')` → `2024060412` | -| [TO_YYYYMMDDHHMMSS](to-yyyymmddhhmmss.md) | 将日期格式化为 YYYYMMDDHHMMSS | `TO_YYYYMMDDHHMMSS('2024-06-04 12:30:45')` → `20240604123045` | -| [DATE_FORMAT](date-format.md) | 按格式字符串格式化日期 | `DATE_FORMAT('2024-06-04', '%Y-%m-%d')` → `'2024-06-04'` | +| [DATE](date.md) | 转换为 DATE 类型 | `DATE('2024-06-04')` → `2024-06-04` | +| [TO_DATE](to-date.md) | 字符串转 DATE 类型 | `TO_DATE('2024-06-04')` → `2024-06-04` | +| [TO_DATETIME](to-datetime.md) | 字符串转 DATETIME 类型 | `TO_DATETIME('2024-06-04 12:30:45')` → `2024-06-04 12:30:45` | +| [TO_TIMESTAMP](to-timestamp.md) | 字符串转 TIMESTAMP 类型 | `TO_TIMESTAMP('2024-06-04 12:30:45')` → `2024-06-04 12:30:45` | +| [TO_UNIX_TIMESTAMP](to-unix-timestamp.md) | 日期转 Unix 时间戳 | `TO_UNIX_TIMESTAMP('2024-06-04')` → `1717516800` | +| [TO_YYYYMM](to-yyyymm.md) | 格式化为 YYYYMM | `TO_YYYYMM('2024-06-04')` → `202406` | +| [TO_YYYYMMDD](to-yyyymmdd.md) | 格式化为 YYYYMMDD | `TO_YYYYMMDD('2024-06-04')` → `20240604` | +| [TO_YYYYMMDDHH](to-yyyymmddhh.md) | 格式化为 YYYYMMDDHH | `TO_YYYYMMDDHH('2024-06-04 12:30:45')` → `2024060412` | +| [TO_YYYYMMDDHHMMSS](to-yyyymmddhhmmss.md) | 格式化为 YYYYMMDDHHMMSS | `TO_YYYYMMDDHHMMSS('2024-06-04 12:30:45')` → `20240604123045` | +| [DATE_FORMAT](date-format.md) | 按指定格式格式化日期 | `DATE_FORMAT('2024-06-04', '%Y-%m-%d')` → `'2024-06-04'` | +| [CONVERT_TIMEZONE](convert-timezone.md) | 转换时间戳至目标时区 | `CONVERT_TIMEZONE('America/Los_Angeles', '2024-11-01 11:36:10')` → `2024-10-31 20:36:10` | ## 日期与时间算术函数 | 函数 | 描述 | 示例 | |------------------------------------------|--------------------------------------------------------------|--------------------------------------------------------------------------------------| -| [DATE_ADD](date-add.md) | 向日期添加时间间隔 | `DATE_ADD(DAY, 7, '2024-06-04')` → `2024-06-11` | -| [DATE_SUB](date-sub.md) | 从日期减去时间间隔 | `DATE_SUB(MONTH, 1, '2024-06-04')` → `2024-05-04` | -| [ADD INTERVAL](addinterval.md) | 向日期添加间隔 | `'2024-06-04' + INTERVAL 1 DAY` → `2024-06-05` | -| [SUBTRACT INTERVAL](subtractinterval.md) | 从日期减去间隔 | `'2024-06-04' - INTERVAL 1 MONTH` → `2024-05-04` | -| [DATE_DIFF](date-diff.md) | 返回两个日期之间的差值 | `DATE_DIFF(DAY, '2024-06-01', '2024-06-04')` → `3` | -| [TIMESTAMP_DIFF](timestamp-diff.md) | 返回两个时间戳之间的差值 | `TIMESTAMP_DIFF(HOUR, '2024-06-04 10:00:00', '2024-06-04 15:00:00')` → `5` | -| [MONTHS_BETWEEN](months-between.md) | 返回两个日期之间的月数 | `MONTHS_BETWEEN('2024-06-04', '2024-01-04')` → `5` | -| [DATE_BETWEEN](date-between.md) | 检查日期是否介于另外两个日期之间 | `DATE_BETWEEN('2024-06-04', '2024-06-01', '2024-06-10')` → `true` | -| [AGE](age.md) | 计算两个时间戳或时间戳与当前日期/时间之间的差值 | `AGE('2000-01-01'::TIMESTAMP, '1990-05-15'::TIMESTAMP)` → `9 years 7 months 17 days` | -| [ADD_MONTHS](add-months.md) | 向日期添加月份,同时保留月末日期 | `ADD_MONTHS('2025-04-30',1)` → `2025-05-31` | +| [DATE_ADD](date-add.md) | 添加时间间隔 | `DATE_ADD(DAY, 7, '2024-06-04')` → `2024-06-11` | +| [DATE_SUB](date-sub.md) | 减去时间间隔 | `DATE_SUB(MONTH, 1, '2024-06-04')` → `2024-05-04` | +| [ADD INTERVAL](addinterval.md) | 添加时间间隔 | `'2024-06-04' + INTERVAL 1 DAY` → `2024-06-05` | +| [SUBTRACT INTERVAL](subtractinterval.md) | 减去时间间隔 | `'2024-06-04' - INTERVAL 1 MONTH` → `2024-05-04` | +| [DATE_DIFF](date-diff.md) | 计算日期差值 | `DATE_DIFF(DAY, '2024-06-01', '2024-06-04')` → `3` | +| [TIMESTAMP_DIFF](timestamp-diff.md) | 计算时间戳差值 | `TIMESTAMP_DIFF(HOUR, '2024-06-04 10:00:00', '2024-06-04 15:00:00')` → `5` | +| [MONTHS_BETWEEN](months-between.md) | 计算月份差值 | `MONTHS_BETWEEN('2024-06-04', '2024-01-04')` → `5` | +| [DATE_BETWEEN](date-between.md) | 判断日期是否在指定范围内 | `DATE_BETWEEN('2024-06-04', '2024-06-01', '2024-06-10')` → `true` | +| [AGE](age.md) | 计算时间差 | `AGE('2000-01-01'::TIMESTAMP, '1990-05-15'::TIMESTAMP)` → `9 years 7 months 17 days` | +| [ADD_MONTHS](add-months.md) | 添加月份(智能处理月末) | `ADD_MONTHS('2025-04-30',1)` → `2025-05-31` | ## 日期与时间截断函数 | 函数 | 描述 | 示例 | |-----------------------------------------------|--------------------------------------------------------|---------------------------------------------------------------------| -| [DATE_TRUNC](date-trunc.md) | 将时间戳截断到指定精度 | `DATE_TRUNC('month', '2024-06-04')` → `2024-06-01` | -| [TIME_SLICE](time-slice.md) | 将单个日期/时间戳值映射到日历对齐的间隔 | `TIME_SLICE('2024-06-04', 4, 'MONTH', 'START')` → `2024-05-01` | -| [TO_START_OF_DAY](to-start-of-day.md) | 返回当天的起始时间 | `TO_START_OF_DAY('2024-06-04 12:30:45')` → `2024-06-04 00:00:00` | -| [TO_START_OF_HOUR](to-start-of-hour.md) | 返回当前小时的起始时间 | `TO_START_OF_HOUR('2024-06-04 12:30:45')` → `2024-06-04 12:00:00` | -| [TO_START_OF_MINUTE](to-start-of-minute.md) | 返回当前分钟的起始时间 | `TO_START_OF_MINUTE('2024-06-04 12:30:45')` → `2024-06-04 12:30:00` | -| [TO_START_OF_MONTH](to-start-of-month.md) | 返回当月的第一天 | `TO_START_OF_MONTH('2024-06-04')` → `2024-06-01` | -| [TO_START_OF_QUARTER](to-start-of-quarter.md) | 返回当季度的第一天 | `TO_START_OF_QUARTER('2024-06-04')` → `2024-04-01` | -| [TO_START_OF_YEAR](to-start-of-year.md) | 返回当年的第一天 | `TO_START_OF_YEAR('2024-06-04')` → `2024-01-01` | -| [TO_START_OF_WEEK](to-start-of-week.md) | 返回当周的第一天 | `TO_START_OF_WEEK('2024-06-04')` → `2024-06-03` | +| [DATE_TRUNC](date-trunc.md) | 按精度截断时间戳 | `DATE_TRUNC('month', '2024-06-04')` → `2024-06-01` | +| [TIME_SLICE](time-slice.md) | 时间分片 | `TIME_SLICE('2024-06-04', 4, 'MONTH', 'START')` → `2024-05-01` | +| [TO_START_OF_DAY](to-start-of-day.md) | 获取当天开始时间 | `TO_START_OF_DAY('2024-06-04 12:30:45')` → `2024-06-04 00:00:00` | +| [TO_START_OF_HOUR](to-start-of-hour.md) | 获取小时开始时间 | `TO_START_OF_HOUR('2024-06-04 12:30:45')` → `2024-06-04 12:00:00` | +| [TO_START_OF_MINUTE](to-start-of-minute.md) | 获取分钟开始时间 | `TO_START_OF_MINUTE('2024-06-04 12:30:45')` → `2024-06-04 12:30:00` | +| [TO_START_OF_MONTH](to-start-of-month.md) | 获取月份第一天 | `TO_START_OF_MONTH('2024-06-04')` → `2024-06-01` | +| [TO_START_OF_QUARTER](to-start-of-quarter.md) | 获取季度第一天 | `TO_START_OF_QUARTER('2024-06-04')` → `2024-04-01` | +| [TO_START_OF_YEAR](to-start-of-year.md) | 获取年份第一天 | `TO_START_OF_YEAR('2024-06-04')` → `2024-01-01` | +| [TO_START_OF_WEEK](to-start-of-week.md) | 获取周第一天 | `TO_START_OF_WEEK('2024-06-04')` → `2024-06-03` | ## 日期与时间导航函数 | 函数 | 描述 | 示例 | |---------------------------------|--------------------------------------------|-------------------------------------------------------| -| [LAST_DAY](last-day.md) | 返回月份的最后一天 | `LAST_DAY('2024-06-04')` → `2024-06-30` | -| [NEXT_DAY](next-day.md) | 返回下一个指定星期几的日期 | `NEXT_DAY('2024-06-04', 'SUNDAY')` → `2024-06-09` | -| [PREVIOUS_DAY](previous-day.md) | 返回上一个指定星期几的日期 | `PREVIOUS_DAY('2024-06-04', 'MONDAY')` → `2024-06-03` | +| [LAST_DAY](last-day.md) | 获取月末日期 | `LAST_DAY('2024-06-04')` → `2024-06-30` | +| [NEXT_DAY](next-day.md) | 获取下一个指定星期几 | `NEXT_DAY('2024-06-04', 'SUNDAY')` → `2024-06-09` | +| [PREVIOUS_DAY](previous-day.md) | 获取上一个指定星期几 | `PREVIOUS_DAY('2024-06-04', 'MONDAY')` → `2024-06-03` | ## 其他日期与时间函数 | 函数 | 描述 | 示例 | |---------------------------|--------------|--------------------------------------------------------------------------| -| [TIMEZONE](timezone.md) | 返回当前时区 | `TIMEZONE()` → `'UTC'` | -| [TIME_SLOT](time-slot.md) | 返回时间槽 | `TIME_SLOT('2024-06-04 12:30:45', 15, 'MINUTE')` → `2024-06-04 12:30:00` | \ No newline at end of file +| [TIMEZONE](timezone.md) | 获取当前时区 | `TIMEZONE()` → `'UTC'` | +| [TIME_SLOT](time-slot.md) | 获取时间槽 | `TIME_SLOT('2024-06-04 12:30:45', 15, 'MINUTE')` → `2024-06-04 12:30:00` | diff --git a/docs/en/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md b/docs/en/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md new file mode 100644 index 0000000000..a9d73a823c --- /dev/null +++ b/docs/en/sql-reference/20-sql-functions/05-datetime-functions/convert-timezone.md @@ -0,0 +1,93 @@ +--- +title: CONVERT_TIMEZONE +--- +import FunctionDescription from '@site/src/components/FunctionDescription'; + + + +`CONVERT_TIMEZONE()` converts a timestamp from the current session timezone (default `UTC`) to the timezone supplied in the first argument. The destination timezone must be a valid [IANA timezone name](https://docs.rs/chrono-tz/latest/chrono_tz/enum.Tz.html). + +## Syntax + +```sql +CONVERT_TIMEZONE(, ) +``` + +| Parameter | Description | +|----------------------|-----------------------------------------------------------------------------| +| `` | Case-sensitive timezone name such as `'America/Los_Angeles'` or `'UTC'`. | +| `` | TIMESTAMP expression (or a value castable to TIMESTAMP). Interpreted using the current session timezone. | + +## Return Type + +Returns a TIMESTAMP value that represents the same instant in the target timezone. + +## Behavior + +- The source timezone always equals the current session timezone (default `UTC`). Configure the session or connection to match the data you are converting. +- Invalid timezone names raise an error. If either argument is `NULL`, the result is `NULL`. +- Daylight-saving gaps can make some timestamps invalid. Turn on `enable_dst_hour_fix = 1` (session or tenant level) so Databend adjusts such values automatically. + +## Examples + +### Convert a single timestamp (default UTC session) + +```sql +SELECT CONVERT_TIMEZONE('America/Los_Angeles', '2024-11-01 11:36:10'); +``` + +``` +┌──────────────────────────────────────────────────────┐ +│ convert_timezone('America/Los_Angeles', '2024-11-01… │ +├──────────────────────────────────────────────────────┤ +│ 2024-11-01 04:36:10.000000 │ +└──────────────────────────────────────────────────────┘ +``` + +### Convert rows using each user's timezone + +```sql +SELECT + user_tz, + event_time, + CONVERT_TIMEZONE(user_tz, event_time) AS local_time +FROM ( + VALUES + ('America/Los_Angeles', '2024-10-31 22:21:15'::TIMESTAMP), + ('Asia/Shanghai', '2024-10-31 22:21:15'::TIMESTAMP), + (NULL, '2024-10-31 22:21:15'::TIMESTAMP) +) AS v(user_tz, event_time) +ORDER BY user_tz NULLS LAST; +``` + +``` +┌──────────────────────┬──────────────────────────────┬──────────────────────────────┐ +│ user_tz │ event_time │ local_time │ +├──────────────────────┼──────────────────────────────┼──────────────────────────────┤ +│ America/Los_Angeles │ 2024-10-31 22:21:15.000000 │ 2024-10-31 15:21:15.000000 │ +│ Asia/Shanghai │ 2024-10-31 22:21:15.000000 │ 2024-11-01 06:21:15.000000 │ +│ NULL │ 2024-10-31 22:21:15.000000 │ NULL │ +└──────────────────────┴──────────────────────────────┴──────────────────────────────┘ +``` + +### Handle timestamps inside DST gaps + +In this session the timezone is configured as Asia/Shanghai and `enable_dst_hour_fix = 1`. The timestamp `1947-04-15 00:00:00` never existed there because clocks jumped forward, so Databend adjusts it before returning the UTC value. + +```sql +SELECT CONVERT_TIMEZONE('UTC', '1947-04-15 00:00:00'); +``` + +``` +┌──────────────────────────────────────────────┐ +│ convert_timezone('UTC', '1947-04-15 00:00:00')│ +├──────────────────────────────────────────────┤ +│ 1947-04-14 15:00:00.000000 │ +└──────────────────────────────────────────────┘ +``` + +## See Also + +- [TIMEZONE](timezone.md) +- [TO_TIMESTAMP_TZ](to-timestamp-tz.md) +- [TO_TIMESTAMP](to-timestamp.md) diff --git a/docs/en/sql-reference/20-sql-functions/05-datetime-functions/index.md b/docs/en/sql-reference/20-sql-functions/05-datetime-functions/index.md index 8234ed25ed..a219c75703 100644 --- a/docs/en/sql-reference/20-sql-functions/05-datetime-functions/index.md +++ b/docs/en/sql-reference/20-sql-functions/05-datetime-functions/index.md @@ -42,6 +42,7 @@ This page provides a comprehensive overview of Date & Time functions in Databend | [TO_YYYYMMDDHH](to-yyyymmddhh.md) | Formats date as YYYYMMDDHH | `TO_YYYYMMDDHH('2024-06-04 12:30:45')` → `2024060412` | | [TO_YYYYMMDDHHMMSS](to-yyyymmddhhmmss.md) | Formats date as YYYYMMDDHHMMSS | `TO_YYYYMMDDHHMMSS('2024-06-04 12:30:45')` → `20240604123045` | | [DATE_FORMAT](date-format.md) | Formats a date according to a format string | `DATE_FORMAT('2024-06-04', '%Y-%m-%d')` → `'2024-06-04'` | +| [CONVERT_TIMEZONE](convert-timezone.md) | Converts a timestamp to the target timezone | `CONVERT_TIMEZONE('America/Los_Angeles', '2024-11-01 11:36:10')` → `2024-10-31 20:36:10` | ## Date & Time Arithmetic Functions