Skip to content

Commit

Permalink
Merge #82523
Browse files Browse the repository at this point in the history
82523: builtins: implement to_timestamp for Unix epoch r=otan a=nnaka2992

fixes #77591

Previously, CockroachDB did not support to_timestamp(double precision)
In PostgreSQL, the function also handles INT, DECIMAL and text by casting,
so the commit also implements those for compatibility.

Release note (sql change): Add new function to_timestamp which
converts Unix epoch of FLOAT, INT, DECIMAL and text to Timestamp with time zone.

Co-authored-by: nnaka2992 <nnaka2992@gmail.com>
  • Loading branch information
craig[bot] and nnaka2992 committed Jun 9, 2022
2 parents 30d4c9d + a7b632a commit ba73ede
Show file tree
Hide file tree
Showing 3 changed files with 211 additions and 0 deletions.
8 changes: 8 additions & 0 deletions docs/generated/sql/functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -655,6 +655,14 @@ has no relationship with the commit order of concurrent transactions.</p>
</span></td></tr>
<tr><td><a name="to_char"></a><code>to_char(timestamp: <a href="timestamp.html">timestamp</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Convert an timestamp to a string assuming the ISO, MDY DateStyle.</p>
</span></td></tr>
<tr><td><a name="to_timestamp"></a><code>to_timestamp(timestamp: <a href="decimal.html">decimal</a>) &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.</p>
</span></td></tr>
<tr><td><a name="to_timestamp"></a><code>to_timestamp(timestamp: <a href="float.html">float</a>) &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.</p>
</span></td></tr>
<tr><td><a name="to_timestamp"></a><code>to_timestamp(timestamp: <a href="int.html">int</a>) &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.</p>
</span></td></tr>
<tr><td><a name="to_timestamp"></a><code>to_timestamp(timestamp: <a href="string.html">string</a>) &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.</p>
</span></td></tr>
<tr><td><a name="transaction_timestamp"></a><code>transaction_timestamp() &rarr; <a href="date.html">date</a></code></td><td><span class="funcdesc"><p>Returns the time of the current transaction.</p>
<p>The value is based on a timestamp picked when the transaction starts
and which stays constant throughout the transaction. This timestamp
Expand Down
83 changes: 83 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/timestamp
Original file line number Diff line number Diff line change
Expand Up @@ -516,3 +516,86 @@ SELECT date_trunc('day', t), date_trunc('hour', t) FROM (VALUES
----
2020-10-25 00:00:00 +0300 EEST 2020-10-25 03:00:00 +0300 EEST
2020-10-25 00:00:00 +0300 EEST 2020-10-25 03:00:00 +0200 EET


# Test for to_timestamp
statement ok
SET TIME ZONE 'UTC'

## Test for to_timestamp without implicit type conversion
query T
SELECT to_timestamp(1646906263.123456)
----
2022-03-10 09:57:43.123456 +0000 UTC

query T
SELECT to_timestamp('1646906263.123456')
----
2022-03-10 09:57:43.123456 +0000 UTC

## Test for to_timestamp with implicit type conversion to int
query T
SELECT to_timestamp(1646906263.123456::INT)
----
2022-03-10 09:57:43 +0000 UTC

query T
SELECT to_timestamp(32767::INT2)
----
1970-01-01 09:06:07 +0000 UTC

query T
SELECT to_timestamp(1646906263.123456::INT4)
----
2022-03-10 09:57:43 +0000 UTC

query T
SELECT to_timestamp(1646906263.123456::INT8)
----
2022-03-10 09:57:43 +0000 UTC

## Test for to_timestamp with implicit type conversion to float
query T
SELECT to_timestamp(1646906263.123456::FLOAT)
----
2022-03-10 09:57:43.123456 +0000 UTC

query T
SELECT to_timestamp(1646906263.123456::REAL)
----
2022-03-10 09:57:43.123456 +0000 UTC

query T
SELECT to_timestamp(1646906263.123456::DOUBLE PRECISION)
----
2022-03-10 09:57:43.123456 +0000 UTC

## Test for to_timestamp with implicit type conversion to decimal
query T
SELECT to_timestamp(1646906263.123456::DECIMAL)
----
2022-03-10 09:57:43.123456 +0000 UTC

## Test for to_timestamp with positive and negative infinities
query T
SELECT to_timestamp('infinity'::DECIMAL)
----
294276-12-31 23:59:59.999999 +0000 UTC

query T
SELECT to_timestamp('-infinity'::DECIMAL)
----
-4713-11-24 00:00:00 +0000 UTC

## Test for to_timestamp with NULL
query T
SELECT to_timestamp(NULL)
----
NULL

## Test for invalid inputs
statement error to_timestamp\(\): invalid input for type text
SELECT to_timestamp('invalid')

statement error unknown signature: to_timestamp\(\)
SELECT to_timestamp()
120 changes: 120 additions & 0 deletions pkg/sql/sem/builtins/builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -2595,6 +2595,113 @@ var builtins = map[string]builtinDefinition{
},
),

// https://www.postgresql.org/docs/14/functions-datetime.html#FUNCTIONS-DATETIME-TABLE
//
// PostgreSQL documents date_trunc for text and double precision.
// It will also handle smallint, integer, bigint, decimal,
// numeric, real, and numeri like text inputs by casting them,
// so we support those for compatibility. This gives us the following
// function signatures:
//
// to_timestamp(text, text) -> TimestampTZ
// to_timestamp(text) -> TimestampTZ
// to_timestamp(INT) -> TimestampTZ
// to_timestamp(INT2) -> TimestampTZ
// to_timestamp(INT4) -> TimestampTZ
// to_timestamp(INT8) -> TimestampTZ
// to_timestamp(FLOAT) -> TimestampTZ
// to_timestamp(REAL) -> TimestampTZ
// to_timestamp(DOUBLE PRECISION) -> TimestampTZ
// to_timestamp(DECIMAL) -> TimestampTZ
//
// See the following snippet from running the functions in PostgreSQL:
//
// postgres=# select to_timestamp(32767::smallint);
// to_timestamp
// ------------------------
// 1970-01-01 09:06:07+00
//
// postgres=# select to_timestamp(1646906263::integer);
// to_timestamp
// ------------------------
// 2022-03-10 09:57:43+00
//
// postgres=# select to_timestamp(1646906263::bigint);
// to_timestamp
// ------------------------
// 2022-03-10 09:57:43+00
//
// postgres=# select to_timestamp(1646906263.123456::decimal);
// to_timestamp
// -------------------------------
// 2022-03-10 09:57:43.123456+00
//
// postgres=# select to_timestamp(1646906263.123456::numeric);
// to_timestamp
// -------------------------------
// 2022-03-10 09:57:43.123456+00
//
// postgres=# select to_timestamp(1646906263.123456::real);
// to_timestamp
// ------------------------
// 2022-03-10 09:57:20+00
//
// postgres=# select to_timestamp('1646906263.123456');
// to_timestamp
// -------------------------------
// 2022-03-10 09:57:43.123456+00
//
"to_timestamp": makeBuiltin(
tree.FunctionProperties{Category: categoryDateAndTime},
tree.Overload{
Types: tree.ArgTypes{{"timestamp", types.String}},
ReturnType: tree.FixedReturnType(types.TimestampTZ),
Fn: func(ctx *eval.Context, args tree.Datums) (tree.Datum, error) {
ts, err := strconv.ParseFloat(string(tree.MustBeDString(args[0])), 64)
if err != nil {
return nil, pgerror.New(pgcode.AmbiguousFunction, "invalid input for type text")
}
return floatToTimestampTZ(ts)
},
Info: "Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.",
Volatility: volatility.Immutable,
},
tree.Overload{
Types: tree.ArgTypes{{"timestamp", types.Int}},
ReturnType: tree.FixedReturnType(types.TimestampTZ),
Fn: func(ctx *eval.Context, args tree.Datums) (tree.Datum, error) {
ts := float64(tree.MustBeDInt(args[0]))
return floatToTimestampTZ(ts)
},
Info: "Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.",
Volatility: volatility.Immutable,
},
tree.Overload{
Types: tree.ArgTypes{{"timestamp", types.Float}},
ReturnType: tree.FixedReturnType(types.TimestampTZ),
Fn: func(ctx *eval.Context, args tree.Datums) (tree.Datum, error) {
ts := float64(tree.MustBeDFloat(args[0]))
return floatToTimestampTZ(ts)
},
Info: "Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.",
Volatility: volatility.Immutable,
},
tree.Overload{
Types: tree.ArgTypes{{"timestamp", types.Decimal}},
ReturnType: tree.FixedReturnType(types.TimestampTZ),
Fn: func(ctx *eval.Context, args tree.Datums) (tree.Datum, error) {
decimal := tree.MustBeDDecimal(args[0]).Decimal
ts, err := decimal.Float64()
if err != nil {
return nil, err
}
return floatToTimestampTZ(ts)
},
Info: "Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp with time zone.",
Volatility: volatility.Immutable,
},
),

// https://www.postgresql.org/docs/10/static/functions-datetime.html
"age": makeBuiltin(
tree.FunctionProperties{},
Expand Down Expand Up @@ -9508,3 +9615,16 @@ func prettyStatement(p tree.PrettyCfg, stmt string) (string, error) {
}
return formattedStmt.String(), nil
}

func floatToTimestampTZ(ts float64) (tree.Datum, error) {
if math.IsNaN(ts) {
return nil, pgerror.New(pgcode.DatetimeFieldOverflow, "timestamp cannot be NaN")
}
if ts == math.Inf(1) {
return tree.MakeDTimestampTZ(pgdate.TimeInfinity, time.Microsecond)
}
if ts == math.Inf(-1) {
return tree.MakeDTimestampTZ(pgdate.TimeNegativeInfinity, time.Microsecond)
}
return tree.MakeDTimestampTZ(timeutil.Unix(0, int64(ts*float64(time.Second))), time.Microsecond)
}

0 comments on commit ba73ede

Please sign in to comment.