Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -43,11 +43,11 @@ The precise fixed-point type [DECIMAL](../sql-data-types/numeric/DECIMAL.md), us

## Date Types

Date types include DATE, TIME and DATETIME, DATE type only stores the date accurate to the day, DATETIME type stores the date and time, which can be accurate to microseconds. TIME type only stores the time, and **does not support the construction of the table storage for the time being, can only be used in the query process**.
Date types include DATE, TIME, DATETIME and TIMESTAMPTZ. DATE type only stores the date accurate to the day, DATETIME type stores the date and time, which can be accurate to microseconds. TIME type only stores the time, and **does not support the construction of the table storage for the time being, can only be used in the query process**. TIMESTAMPTZ is a time zone-aware date-time type that stores values in UTC and automatically converts them based on the session time zone during queries.

Do calculation for datetime types or converting them to numeric types, please use functions like [TIME_TO_SEC](../../sql-functions/scalar-functions/date-time-functions/time-to-sec), [DATE_DIFF](../../sql-functions/scalar-functions/date-time-functions/datediff), [UNIX_TIMESTAMP](../../sql-functions/scalar-functions/date-time-functions/unix-timestamp) . The result of directly converting them as numeric types as not guaranteed.

For more information refer to [DATE](../sql-data-types/date-time/DATE), [TIME](../sql-data-types/date-time/TIME) and [DATETIME](../sql-data-types/date-time/DATETIME) documents.
For more information refer to [DATE](../sql-data-types/date-time/DATE), [TIME](../sql-data-types/date-time/TIME), [DATETIME](../sql-data-types/date-time/DATETIME) and [TIMESTAMPTZ](../sql-data-types/date-time/TIMESTAMPTZ) documents.



Expand Down
105 changes: 105 additions & 0 deletions docs/sql-manual/basic-element/sql-data-types/date-time/TIMESTAMPTZ.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
---
{
"title": "TIMESTAMPTZ",
"language": "en"
}
---

## Description

TIMESTAMPTZ is the data type in Doris used to store date and time information with time zone awareness, corresponding to TIMESTAMP WITH TIME ZONE in standard SQL.

In different database systems, time zone-aware timestamp types have various naming conventions:
- PostgreSQL and Oracle use TIMESTAMP WITH TIME ZONE
- SQL Server uses DATETIMEOFFSET
- Some other databases use TIMESTAMP WITH LOCAL TIME ZONE

According to SQL standards, the standalone TIMESTAMP type should not carry time zone information (equivalent to TIMESTAMP WITHOUT TIME ZONE). Considering user habits and ease of use, Doris chose the more concise name TIMESTAMPTZ to represent the timestamp type with time zone. Note that currently Doris does not have a separate TIMESTAMP type, as users can effectively use DATETIME to store time information.

The range of TIMESTAMPTZ is the same as DATETIME, being `[0000-01-01 00:00:00.000000, 9999-12-31 23:59:59.999999]`, with a fixed microsecond precision. The default output format is 'yyyy-MM-dd HH:mm:ss.SSSSSS +XX:XX', where +XX:XX represents the time zone offset.

### Working Principle

TIMESTAMPTZ implementation does not store time zone information with each row of data, but instead adopts the following mechanism:
1. During storage: All input time values are converted to UTC (Coordinated Universal Time)
2. During query: Based on the session's time zone setting (specified via the `time_zone` variable), UTC time is automatically converted to the corresponding time zone for display

Therefore, TIMESTAMPTZ can be understood as a DATETIME type with time zone conversion functionality, where Doris automatically handles time zone conversions internally.

### Time Zone Handling Rules

- When input strings contain time zone information (e.g., "2020-01-01 00:00:00 +03:00"), Doris uses that time zone information for conversion
- When input strings do not contain time zone information (e.g., "2020-01-01 00:00:00"), Doris uses the current session's time zone setting for conversion

### Storage and Usage

In Doris, a TIMESTAMPTZ type field occupies 8 bytes of storage space.

TIMESTAMPTZ and DATETIME types support mutual conversion, with appropriate time zone adjustments during conversion. TIMESTAMPTZ supports implicit conversion to DATETIME, allowing functions that do not directly support TIMESTAMPTZ to process this type of data.

## Examples

```sql
-- Using the current time zone (assuming +08:00) to convert a time string without time zone information
select cast("2020-01-01 00:00:00" as timestamptz);
```

```text
+--------------------------------------------+
| cast("2020-01-01 00:00:00" as timestamptz) |
+--------------------------------------------+
| 2020-01-01 00:00:00.000000 +08:00 |
+--------------------------------------------+
```

```sql
-- Using a time string with time zone information
select cast("2020-01-01 00:00:00 +03:00" as timestamptz);
```

```text
+---------------------------------------------------+
| cast("2020-01-01 00:00:00 +03:00" as timestamptz) |
+---------------------------------------------------+
| 2020-01-01 00:00:00.000000 +03:00 |
+---------------------------------------------------+
```

```sql
-- Converting TIMESTAMPTZ to DATETIME (with time zone conversion based on current time zone)
select cast(cast("2020-01-01 00:00:00 +03:00" as timestamptz) as datetime);
```

```text
+----------------------------------------------------------------------+
| cast(cast("2020-01-01 00:00:00 +03:00" as timestamptz) as datetime ) |
+----------------------------------------------------------------------+
| 2020-01-01 05:00:00 |
+----------------------------------------------------------------------+
```

```sql
-- Converting DATETIME to TIMESTAMPTZ
select cast(cast('2023-01-02 01:00:00' as datetime) as timestamptz);
```

```text
+----------------------------------------------------------------+
| cast(cast('2023-01-02 01:00:00' as datetime) as timestamptz ) |
+----------------------------------------------------------------+
| 2023-01-02 01:00:00.000000 +08:00 |
+----------------------------------------------------------------+
```

```sql
-- Using TIMESTAMPTZ in functions
select HOUR(cast("2020-01-01 00:00:00 +03:00" as timestamptz));
```

```text
+---------------------------------------------------------+
| HOUR(cast("2020-01-01 00:00:00 +03:00" as timestamptz)) |
+---------------------------------------------------------+
| 5 |
+---------------------------------------------------------+
```
Original file line number Diff line number Diff line change
Expand Up @@ -38,11 +38,11 @@

## 日期类型

日期类型包括 DATE、TIME 和 DATETIME,DATE 类型只存储日期精确到天,DATETIME 类型存储日期和时间,可以精确到微秒。TIME 类型只存储时间,且**暂时不支持建表存储,只能在查询过程中使用**。
日期类型包括 DATE、TIME、DATETIMETIMESTAMPTZ,DATE 类型只存储日期精确到天,DATETIME 类型存储日期和时间,可以精确到微秒。TIME 类型只存储时间,且**暂时不支持建表存储,只能在查询过程中使用**。TIMESTAMPTZ 是带时区信息的日期时间类型,存储时转换为 UTC 时间,查询时根据会话时区自动转换显示

对日期类型进行计算,或将其转换为数字,请使用类似 [TIME_TO_SEC](../../sql-functions/scalar-functions/date-time-functions/time-to-sec), [DATE_DIFF](../../sql-functions/scalar-functions/date-time-functions/datediff), [UNIX_TIMESTAMP](../../sql-functions/scalar-functions/date-time-functions/unix-timestamp) 等函数,直接将其 CAST 为数字类型的结果不受保证。在未来的版本中,此类 CAST 行为将会被禁止。

更多信息参考 [DATE](../../basic-element/sql-data-types/date-time/DATE)、[TIME](../../basic-element/sql-data-types/date-time/TIME) 和 [DATETIME](../../basic-element/sql-data-types/date-time/DATETIME) 文档。
更多信息参考 [DATE](../../basic-element/sql-data-types/date-time/DATE)、[TIME](../../basic-element/sql-data-types/date-time/TIME)、[DATETIME](../../basic-element/sql-data-types/date-time/DATETIME) 和 [TIMESTAMPTZ](../../basic-element/sql-data-types/date-time/TIMESTAMPTZ) 文档。


## 字符串类型
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,106 @@
---
{
"title": "TIMESTAMPTZ",
"language": "zh-CN"
}
---

## 描述

TIMESTAMPTZ 是 Doris 中用于存储带时区信息的日期时间数据类型,对应于标准 SQL 中的 TIMESTAMP WITH TIME ZONE。

在不同数据库系统中,带时区的时间戳类型有多种命名方式:
- PostgreSQL 和 Oracle 使用 TIMESTAMP WITH TIME ZONE
- SQL Server 使用 DATETIMEOFFSET
- 其他一些数据库使用 TIMESTAMP WITH LOCAL TIME ZONE

根据 SQL 标准,单独的 TIMESTAMP 类型不应携带时区信息(等同于 TIMESTAMP WITHOUT TIME ZONE)。考虑到用户习惯和使用便捷性,Doris 选择使用 TIMESTAMPTZ 这个更加简洁的命名来表示带时区的时间戳类型。
注意目前Doris没有一个单独的TIMESTAMP类型,实际上用户完全可以使用DATETIME来存储时间。

TIMESTAMPTZ 的取值范围与 DATETIME 相同,为 `[0000-01-01 00:00:00.000000, 9999-12-31 23:59:59.999999]`,精度固定为微秒级别。默认输出格式为 'yyyy-MM-dd HH:mm:ss.SSSSSS +XX:XX',其中 +XX:XX 表示时区偏移量。

### 工作原理

TIMESTAMPTZ 的实现并非在每行数据中单独存储时区信息,而是采用以下机制:
1. 存储时:将输入的时间值统一转换为 UTC(世界协调时间)存储
2. 查询时:根据会话的时区设置(通过 `time_zone` 变量指定),将 UTC 时间自动转换为相应时区的时间进行展示

因此,TIMESTAMPTZ 可以理解为一个带有时区转换功能的 DATETIME 类型,Doris 在内部自动完成时区的转换处理。

### 时区处理规则

- 当输入字符串包含时区信息(如 "2020-01-01 00:00:00 +03:00")时,Doris 会使用该时区信息进行转换
- 当输入字符串不包含时区信息(如 "2020-01-01 00:00:00")时,Doris 会使用当前会话的时区设置进行转换

### 存储与使用

在 Doris 中,一个 TIMESTAMPTZ 类型字段占用 8 字节存储空间。

TIMESTAMPTZ 与 DATETIME 类型之间支持相互转换,转换过程中会根据时区进行适当调整。TIMESTAMPTZ 支持隐式转换为 DATETIME,这使得不直接支持 TIMESTAMPTZ 的函数也能处理此类型的数据。

## 举例

```sql
-- 使用当前时区(假设为 +08:00)转换没有时区信息的时间字符串
select cast("2020-01-01 00:00:00" as timestamptz);
```

```text
+--------------------------------------------+
| cast("2020-01-01 00:00:00" as timestamptz) |
+--------------------------------------------+
| 2020-01-01 00:00:00.000000 +08:00 |
+--------------------------------------------+
```

```sql
-- 使用带有时区信息的时间字符串
select cast("2020-01-01 00:00:00 +03:00" as timestamptz);
```

```text
+---------------------------------------------------+
| cast("2020-01-01 00:00:00 +03:00" as timestamptz) |
+---------------------------------------------------+
| 2020-01-01 00:00:00.000000 +03:00 |
+---------------------------------------------------+
```

```sql
-- TIMESTAMPTZ 转换为 DATETIME(会根据当前时区进行转换)
select cast(cast("2020-01-01 00:00:00 +03:00" as timestamptz) as datetime);
```

```text
+----------------------------------------------------------------------+
| cast(cast("2020-01-01 00:00:00 +03:00" as timestamptz) as datetime ) |
+----------------------------------------------------------------------+
| 2020-01-01 05:00:00 |
+----------------------------------------------------------------------+
```

```sql
-- 将 DATETIME 转换为 TIMESTAMPTZ
select cast(cast('2023-01-02 01:00:00' as datetime) as timestamptz);
```

```text
+----------------------------------------------------------------+
| cast(cast('2023-01-02 01:00:00' as datetime) as timestamptz ) |
+----------------------------------------------------------------+
| 2023-01-02 01:00:00.000000 +08:00 |
+----------------------------------------------------------------+
```

```sql
-- 在函数中使用 TIMESTAMPTZ
select HOUR(cast("2020-01-01 00:00:00 +03:00" as timestamptz));
```

```text
+---------------------------------------------------------+
| HOUR(cast("2020-01-01 00:00:00 +03:00" as timestamptz)) |
+---------------------------------------------------------+
| 5 |
+---------------------------------------------------------+
```
1 change: 1 addition & 0 deletions sidebars.json
Original file line number Diff line number Diff line change
Expand Up @@ -1029,6 +1029,7 @@
"sql-manual/basic-element/sql-data-types/date-time/DATE",
"sql-manual/basic-element/sql-data-types/date-time/TIME",
"sql-manual/basic-element/sql-data-types/date-time/DATETIME",
"sql-manual/basic-element/sql-data-types/date-time/TIMESTAMPTZ",
"admin-manual/cluster-management/time-zone"
]
},
Expand Down