Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

builtins: implement to_timestamp for Unix epoch #82523

Merged
merged 1 commit into from
Jun 9, 2022
Merged
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
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')
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

can you add test cases for NaN too

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Added test of to_timestamp() for testing NaN.


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
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This PR adds overloads that do not exist in Postgres. The only two overloads in PG are to_timestamp(double_precision) and to_timestamp(text, text).

All of these other examples work because the argument type can be implicitly cast to a FLOAT8, or they are parsed as numeric types, as in to_timestamp('1646906263.123456').

Copy link
Contributor Author

@nnaka2992 nnaka2992 Jun 9, 2022

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

It is better if we can implicitly cast (or parse) text to numeric on function call. However at least on v22, CockroachDB
does not perform implicit casting, so I added the overload, to_timestamp(text) for compatibility.

Is it much suitable to fix overload.go (or any other files) to parse text as numeric?

//
"to_timestamp": makeBuiltin(
tree.FunctionProperties{Category: categoryDateAndTime},
tree.Overload{
Types: tree.ArgTypes{{"timestamp", types.String}},
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The string overload should take two string arguments. https://www.postgresql.org/docs/current/functions-formatting.html

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

would this be the same as experimental_strptime?

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

It's similar, but experimental_strptime doesn't support the same formatting strings as to_timestamp. Here's an example from the Postgres docs:

defaultdb> select experimental_strptime('05 Dec 2000', 'DD Mon YYYY');
  experimental_strptime
--------------------------
  0001-01-01 00:00:00+00

The result should be 2000-12-05 00:00:00-05 (assuming the timezone is set to -05). It looks like experimental_strptime returns a default value when parsing fails, rather than erring.

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,
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I believe this should be stable, not immutable. In Postgres:

marcus=# select proargtypes, prorettype::regtype, provolatile, proleakproof from pg_proc where proname = 'to_timestamp';
 proargtypes |        prorettype        | provolatile | proleakproof
-------------+--------------------------+-------------+--------------
 701         | timestamp with time zone | i           | f
 25 25       | timestamp with time zone | s           | f
(2 rows)

marcus=# select 701::oid::regtype, 25::oid::regtype;
     regtype      | regtype
------------------+---------
 double precision | text
(1 row)

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The one arg version is immutable - so this is right right?

},
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 @@ -9629,3 +9736,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)
}