Skip to content

Commit

Permalink
Document the TIMETZ type
Browse files Browse the repository at this point in the history
Fixes #2982

Summary of changes:

- Make clear that TIMETZ is not really recommended, just there for SQL
  standard and ORM support (2.1)

- Give examples of wonkiness: comparisons and ordering (2.1)

- Update SQL Feature page with TIME data type (2.0 and 2.1)

- Update example to use TIME, not TIMETZ

- Add links to other related docs as appropriate: Postgres time stuff
  and wire protocol, Cockroach SQL feature page and functions/operators

- Fixed a few small typos/copy-edits

- Also minor tweaks to the TIMEZONE type docs
  • Loading branch information
jseldess authored and rmloveland committed May 9, 2018
1 parent 848119b commit c69ba36
Show file tree
Hide file tree
Showing 6 changed files with 94 additions and 40 deletions.
1 change: 1 addition & 0 deletions v2.0/sql-feature-support.md
Original file line number Diff line number Diff line change
Expand Up @@ -43,6 +43,7 @@ table tr td:nth-child(2) {
| <span class="version-tag">New in v1.1:</span> `ARRAY` || Standard | [`ARRAY` documentation](array.html) |
| <span class="version-tag">New in v1.1:</span> `UUID` || PostgreSQL Extension | [`UUID` documentation](uuid.html) |
| <span class="version-tag">New in v2.0:</span> JSON || Common Extension | [`JSONB` documentation](jsonb.html) |
| <span class="version-tag">New in v2.0:</span> `TIME` || Standard | [`TIME` documentation](time.html) |
| XML || Standard | XML data can be stored as `BYTES`, but we do not offer XML parsing. |
| `UNSIGNED INT` || Common Extension | `UNSIGNED INT` causes numerous casting issues, so we don't plan to support it. |
| `SET`, `ENUM` || MySQL, PostgreSQL Extension | Only allow rows to contain values from a defined set of terms. |
Expand Down
3 changes: 2 additions & 1 deletion v2.0/time.md
Original file line number Diff line number Diff line change
Expand Up @@ -84,4 +84,5 @@ Type | Details

## See Also

[Data Types](data-types.html)
- [Data Types](data-types.html)
- [SQL Feature Support](sql-feature-support.html)
6 changes: 4 additions & 2 deletions v2.1/data-types.md
Original file line number Diff line number Diff line change
Expand Up @@ -23,8 +23,10 @@ Type | Description | Example
[`JSONB`](jsonb.html) | <span class="version-tag">New in v2.0:</span> JSON (JavaScript Object Notation) data. | `'{"first_name": "Lola", "last_name": "Dog", "location": "NYC", "online" : true, "friends" : 547}'`
[`SERIAL`](serial.html) | A unique 64-bit signed integer. | `148591304110702593 `
[`STRING`](string.html) | A string of Unicode characters. | `'a1b2c3'`
[`TIME`](time.html) | <span class="version-tag">New in v2.0:</span> A time of day with no time zone. | `TIME '01:23:45.123456'`
[`TIMESTAMP`](timestamp.html) | A date and time pairing. | `TIMESTAMP '2016-01-25 10:10:10'`
[`TIME`](time.html) | <span class="version-tag">New in v2.0:</span> A time of day in UTC. | `TIME '01:23:45.123456'`
[`TIMETZ`](time.html) | <span class="version-tag">New in v2.1:</span> A time of day with a time zone offset from UTC. | `TIMETZ '01:23:45.123456-5:00'`
[`TIMESTAMP`](timestamp.html) | A date and time pairing in UTC. | `TIMESTAMP '2016-01-25 10:10:10'`
[`TIMESTAMPTZ`](timestamp.html) | A date and time pairing with a time zone offset from UTC. | `TIMESTAMPTZ '2016-01-25 10:10:10-05:00'`
[`UUID`](uuid.html) | A 128-bit hexadecimal value. | `7f9c24e8-3b12-4fef-91e0-56a2d5a246ec`

## Data Type Conversions & Casts
Expand Down
1 change: 1 addition & 0 deletions v2.1/sql-feature-support.md
Original file line number Diff line number Diff line change
Expand Up @@ -43,6 +43,7 @@ table tr td:nth-child(2) {
| <span class="version-tag">New in v1.1:</span> `ARRAY` || Standard | [`ARRAY` documentation](array.html) |
| <span class="version-tag">New in v1.1:</span> `UUID` || PostgreSQL Extension | [`UUID` documentation](uuid.html) |
| <span class="version-tag">New in v2.0:</span> JSON || Common Extension | [`JSONB` documentation](jsonb.html) |
| <span class="version-tag">New in v2.0:</span> `TIME` || Standard | [`TIME` documentation](time.html) |
| XML || Standard | XML data can be stored as `BYTES`, but we do not offer XML parsing. |
| `UNSIGNED INT` || Common Extension | `UNSIGNED INT` causes numerous casting issues, so we don't plan to support it. |
| `SET`, `ENUM` || MySQL, PostgreSQL Extension | Only allow rows to contain values from a defined set of terms. |
Expand Down
103 changes: 76 additions & 27 deletions v2.1/time.md
Original file line number Diff line number Diff line change
@@ -1,77 +1,125 @@
---
title: TIME
summary: The TIME data type stores a time of day without a time zone.
summary: The TIME data type stores a time of day in UTC, whereas TIMETZ stores a time of day with a time zone offset from UTC.
toc: false
---
<span class="version-tag">New in v2.0:</span> The `TIME` [data type](data-types.html) stores the time of day without a time zone.
<span class="version-tag">New in v2.0:</span> The `TIME` [data type](data-types.html) stores the time of day in UTC, whereas `TIMETZ` stores a time of day with a time zone offset from UTC.

<div id="toc"></div>

## Variants

`TIME` has two variants:

- `TIME` presents all `TIME` values in UTC.

- `TIMETZ` converts `TIME` values from UTC to the client's session time zone (unless another time zone is specified for the value). However, it is conceptually important to note that `TIMETZ` **does not** store any time zone data.

{{site.data.alerts.callout_info}}The default session time zone is UTC, which means that by default <code>TIMETZ</code> values display in UTC.{{site.data.alerts.end}}

The difference between these two variants is that `TIMETZ` uses the client's session time zone, while `TIME` does not. This behavior extends to [functions like `now()` and `extract()`](functions-and-operators.html#date-and-time-functions) on `TIMETZ` values.

## Best Practices

We recommend always using `TIME` because the `TIMETZ` variant can lead to unexpected behavior when:

- Comparing `TIMETZ` instances using [operators such as `>`](functions-and-operators.html#operators)
- [Ordering query results](query-order.html) which include `TIMETZ` values in time order, e.g., `SELECT * FROM table ORDER BY column_with_timetz_type`.

[Like Postgres](https://www.postgresql.org/docs/current/static/datatype-datetime.html), we implement the `TIMETZ` variant for [SQL standards compliance](sql-feature-support.html), and also because it is used by ORMs like [Hibernate](build-a-java-app-with-cockroachdb-hibernate.html).

## Aliases

In CockroachDB, the following are aliases:
The `TIME` data types are aliased as shown below.

- `TIME WITHOUT TIME ZONE`
| Alias | Long Version |
|----------+--------------------------|
| `TIME` | `TIME WITHOUT TIME ZONE` |
| `TIMETZ` | `TIME WITH TIME ZONE` |

## Syntax

A constant value of type `TIME` can be expressed using an
A constant value of type `TIME`/`TIMETZ` can be expressed using an
[interpreted literal](sql-constants.html#interpreted-literals), or a
string literal
[annotated with](scalar-expressions.html#explicitly-typed-expressions)
type `TIME` or
type `TIME`/`TIMETZ` or
[coerced to](scalar-expressions.html#explicit-type-coercions) type
`TIME`.
`TIME`/`TIMETZ`.

The string format for time is `HH:MM:SS.SSSSSS`. For example: `TIME '05:40:00.000001'`.

CockroachDB also supports using uninterpreted
[string literals](sql-constants.html#string-literals) in contexts
where a `TIME` value is otherwise expected.
To express a `TIMETZ` value (with time zone offset from UTC), use
the following format: `TIMETZ '10:10:10.555555-05:00'`

The fractional portion of `TIME` is optional and is rounded to microseconds (i.e., six digits after the decimal) for compatibility with the PostgreSQL wire protocol.
When it is unambiguous, a simple unannotated [string literal](sql-constants.html#string-literals) can also
be automatically interpreted as type `TIME` or `TIMETZ`.

Note that the fractional portion of `TIME`/`TIMETZ` is optional and is rounded to microseconds (i.e., six digits after the decimal) for compatibility with the [PostgreSQL wire protocol](https://www.postgresql.org/docs/current/static/protocol.html).

## Size

A `TIME` column supports values up to 8 bytes in width, but the total storage size is likely to be larger due to CockroachDB metadata.
A `TIME`/`TIMETZ` column supports values up to 8 bytes in width, but the total storage size is likely to be larger due to CockroachDB metadata.

## Example

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE time (a INT PRIMARY KEY, b TIME);
> CREATE TABLE time (time_id INT PRIMARY KEY, time_val TIME);
~~~

{% include copy-clipboard.html %}
~~~ sql
> SHOW COLUMNS FROM time;
~~~
~~~
+-------+------+-------+---------+-------------+
| Field | Type | Null | Default | Indices |
+-------+------+-------+---------+-------------+
| a | INT | false | NULL | {"primary"} |
| b | TIME | true | NULL | {} |
+-------+------+-------+---------+-------------+
+----------+------+------+---------+-------------+
| Field | Type | Null | Default | Indices |
+----------+------+------+---------+-------------+
| time_id | INT | f | NULL | {"primary"} |
| time_val | TIME | t | NULL | {} |
+----------+------+------+---------+-------------+
(2 rows)
~~~

{% include copy-clipboard.html %}
~~~ sql
> INSERT INTO time VALUES (1, TIME '05:40:00');
> INSERT INTO time VALUES (1, TIME '05:40:00'), (2, TIME '05:41:39');
~~~

{% include copy-clipboard.html %}
~~~ sql
> SELECT * FROM time;
~~~
~~~
+---+---------------------------+
| a | b |
+---+---------------------------+
| 1 | 0000-01-01 05:40:00+00:00 |
+---+---------------------------+
+---------+---------------------------+
| time_id | time_val |
+---------+---------------------------+
| 1 | 0000-01-01 05:40:00+00:00 |
| 2 | 0000-01-01 05:41:39+00:00 |
+---------+---------------------------+
(2 rows)
~~~

{{site.data.alerts.callout_info}}The <code>cockroach sql</code> shell displays the date and time zone due to the Go SQL driver it uses. Other client drivers may behave similarly. In such cases, however, the date and time zone are not relevant and are not stored in the database.{{site.data.alerts.end}}

Comparing `TIME` values:

{% include copy-clipboard.html %}
~~~ sql
> SELECT (SELECT time_val FROM time WHERE time_id = 1) < (SELECT time_val FROM time WHERE time_id = 2);
~~~
~~~
+--------------------------------+
| (SELECT time_val FROM "time" |
| WHERE time_id = 1) < (SELECT |
| time_val FROM "time" WHERE |
| time_id = 2) |
+--------------------------------+
| true |
+--------------------------------+
(1 row)
~~~
{{site.data.alerts.callout_info}}The <code>cockroach sql</code> shell displays the date and timezone due to the Go SQL driver it uses. Other client drivers may behave similarly. In such cases, however, the date and timezone are not relevant and are not stored in the database.{{site.data.alerts.end}}

## Supported Casting & Conversion

Expand All @@ -84,4 +132,5 @@ Type | Details

## See Also

[Data Types](data-types.html)
- [Data Types](data-types.html)
- [SQL Feature Support](sql-feature-support.html)
20 changes: 10 additions & 10 deletions v2.1/timestamp.md
Original file line number Diff line number Diff line change
Expand Up @@ -4,25 +4,25 @@ summary: The TIMESTAMP data type stores a date and time pair in UTC, whereas TIM
toc: false
---

The `TIMESTAMP` [data type](data-types.html) stores a date and time pair in UTC.
The `TIMESTAMP` [data type](data-types.html) stores a date and time pair in UTC, whereas `TIMESTAMPTZ` stores a date and time pair with a time zone offset from UTC.

<div id="toc"></div>

## Time Zone Details
## Variants

`TIMESTAMP` has two variants:

- `TIMESTAMP WITH TIME ZONE` converts `TIMESTAMP` values from UTC to the client's session time zone (unless another time zone is specified for the value). However, it is conceptually important to note that `TIMESTAMP WITH TIME ZONE` *does not* store any time zone data.
- `TIMESTAMP` presents all `TIMESTAMP` values in UTC.

{{site.data.alerts.callout_info}}The default session time zone is UTC, which means that by default `TIMESTAMP WITH TIME ZONE` values display in UTC.{{site.data.alerts.end}}
- `TIMESTAMPTZ` converts `TIMESTAMP` values from UTC to the client's session time zone (unless another time zone is specified for the value). However, it is conceptually important to note that `TIMESTAMPTZ` **does not** store any time zone data.

- `TIMESTAMP WITHOUT TIME ZONE` presents all `TIMESTAMP` values in UTC.
{{site.data.alerts.callout_info}}The default session time zone is UTC, which means that by default <code>TIMESTAMPTZ</code> values display in UTC.{{site.data.alerts.end}}

The difference between these two types is that `TIMESTAMP WITH TIME ZONE` uses the client's session time zone, while the other simply does not. This behavior extends to functions like `now()` and `extract()` on `TIMESTAMP WITH TIME ZONE` values.
The difference between these two variants is that `TIMESTAMPTZ` uses the client's session time zone, while the other simply does not. This behavior extends to functions like `now()` and `extract()` on `TIMESTAMPTZ` values.

### Best Practices
## Best Practices

We recommend always using the `...WITH TIME ZONE` variant because the `...WITHOUT TIME ZONE` variant can sometimes lead to unexpected behaviors when it ignores a session offset. However, we also recommend you avoid setting a session time for your database.
We recommend always using the `TIMESTAMPTZ` variant because the `TIMESTAMP` variant can sometimes lead to unexpected behaviors when it ignores a session offset. However, we also recommend you avoid setting a session time for your database.

## Aliases

Expand Down Expand Up @@ -53,7 +53,7 @@ ISO 8601 | `TIMESTAMP '2016-01-25T10:10:10.555555'`
To express a `TIMESTAMPTZ` value (with time zone offset from UTC), use
the following format: `TIMESTAMPTZ '2016-01-25 10:10:10.555555-05:00'`

When it is unambiguous, a simple unannotated string literal can also
When it is unambiguous, a simple unannotated [string literals](sql-constants.html#string-literals) can also
be automatically interpreted as type `TIMESTAMP` or `TIMESTAMPTZ`.

Note that the fractional portion is optional and is rounded to
Expand All @@ -62,7 +62,7 @@ PostgreSQL wire protocol.

## Size

A `TIMESTAMP` column supports values up to 12 bytes in width, but the total storage size is likely to be larger due to CockroachDB metadata.
A `TIMESTAMP`/`TIMESTAMPTZ` column supports values up to 12 bytes in width, but the total storage size is likely to be larger due to CockroachDB metadata.

## Examples

Expand Down

0 comments on commit c69ba36

Please sign in to comment.