-
Notifications
You must be signed in to change notification settings - Fork 3.8k
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
Changes from all commits
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -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 | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe 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 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 There was a problem hiding this comment. Choose a reason for hiding this commentThe 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 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}}, | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe 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 There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. would this be the same as There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. It's similar, but
The result should be |
||
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, | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I believe this should be stable, not immutable. In Postgres:
There was a problem hiding this comment. Choose a reason for hiding this commentThe 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{}, | ||
|
@@ -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) | ||
} |
There was a problem hiding this comment.
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
There was a problem hiding this comment.
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.