Skip to content

Commit

Permalink
sql: add parse_timestamp builtin
Browse files Browse the repository at this point in the history
Add a builtin that can be used to parse timestamp strings. This is
like a cast, but it does not accept relative timestamps so it can be
immutable.

Only immutable expressions are allowed in computed column expressions
or partial index predicates; unlike casts, the new function can be
used in such expressions.

Fixes cockroachdb#60578.

Release notes (sql change): A new parse_timestamp function can be used
to parse absolute timestamp strings in computed column expressions or
partial index predicates.
  • Loading branch information
RaduBerinde committed Feb 19, 2021
1 parent 58216a6 commit 5bd05a1
Show file tree
Hide file tree
Showing 3 changed files with 80 additions and 0 deletions.
2 changes: 2 additions & 0 deletions docs/generated/sql/functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -2371,6 +2371,8 @@ to recreate a database.’</p>
</span></td></tr>
<tr><td><a name="overlay"></a><code>overlay(input: <a href="string.html">string</a>, overlay_val: <a href="string.html">string</a>, start_pos: <a href="int.html">int</a>, end_pos: <a href="int.html">int</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Deletes the characters in <code>input</code> between <code>start_pos</code> and <code>end_pos</code> (count starts at 1), and then insert <code>overlay_val</code> at <code>start_pos</code>.</p>
</span></td></tr>
<tr><td><a name="parse_timestamp"></a><code>parse_timestamp(string: <a href="string.html">string</a>) &rarr; <a href="timestamp.html">timestamp</a></code></td><td><span class="funcdesc"><p>Convert a string containing an absolute timestamp to the corresponding timestamp.</p>
</span></td></tr>
<tr><td><a name="pg_collation_for"></a><code>pg_collation_for(str: anyelement) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Returns the collation of the argument</p>
</span></td></tr>
<tr><td><a name="quote_ident"></a><code>quote_ident(val: <a href="string.html">string</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Return <code>val</code> suitably quoted to serve as identifier in a SQL statement.</p>
Expand Down
53 changes: 53 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/datetime
Original file line number Diff line number Diff line change
Expand Up @@ -1703,3 +1703,56 @@ query TT
SELECT 'infinity'::timestamp, '-infinity'::timestamptz
----
294276-12-31 23:59:59.999999 +0000 +0000 -4713-11-24 00:00:00 +0000 +0000

query T
SELECT parse_timestamp('2020-01-02 01:02:03')
----
2020-01-02 01:02:03 +0000 +0000

query error could not parse
SELECT parse_timestamp('foo')

query error parse_timestamp\(\): relative timestamps are not supported
SELECT parse_timestamp('now')

query error parse_timestamp\(\): relative timestamps are not supported
SELECT parse_timestamp('tomorrow')

# Verify that parse_timestamp can be used in computed column expressions.
statement ok
CREATE TABLE timestamps (s STRING, ts TIMESTAMP AS (parse_timestamp(s)) STORED)

query error parse_timestamp\(\): relative timestamps are not supported
INSERT INTO timestamps VALUES ('tomorrow')

statement ok
INSERT INTO timestamps VALUES ('2020-01-02 01:02:03'), ('2015-08-25 04:45:45.53453+01:00'), (NULL)

query TT colnames
SELECT * FROM timestamps ORDER BY s
----
s ts
NULL NULL
2015-08-25 04:45:45.53453+01:00 2015-08-25 04:45:45.53453 +0000 +0000
2020-01-02 01:02:03 2020-01-02 01:02:03 +0000 +0000

statement ok
SET TIME ZONE 'America/New_York'

# Insert the same values again (stored columns are computed on insert).
statement ok
INSERT INTO timestamps VALUES ('2020-01-02 01:02:03'), ('2015-08-25 04:45:45.53453+01:00'), (NULL)

query TT colnames
SELECT * FROM timestamps ORDER BY s
----
s ts
NULL NULL
NULL NULL
2015-08-25 04:45:45.53453+01:00 2015-08-25 04:45:45.53453 +0000 +0000
2015-08-25 04:45:45.53453+01:00 2015-08-25 04:45:45.53453 +0000 +0000
2020-01-02 01:02:03 2020-01-02 01:02:03 +0000 +0000
2020-01-02 01:02:03 2020-01-02 01:02:03 +0000 +0000

statement ok
RESET TIME ZONE
25 changes: 25 additions & 0 deletions pkg/sql/sem/builtins/builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -2734,6 +2734,31 @@ may increase either contention or retry errors, or both.`,
},
),

// parse_timestamp converts strings to timestamps. It is useful in expressions
// where casts (which are not immutable) cannot be used, like computed column
// expressions or partial index predicates. Only absolute timestamps that do
// not depend on the current context are supported (relative timestamps like
// 'now' are not supported).
"parse_timestamp": makeBuiltin(defProps(),
tree.Overload{
Types: tree.ArgTypes{{"string", types.String}},
ReturnType: tree.FixedReturnType(types.Timestamp),
Fn: func(ctx *tree.EvalContext, args tree.Datums) (tree.Datum, error) {
arg := string(tree.MustBeDString(args[0]))
ts, dependsOnContext, err := tree.ParseDTimestamp(ctx, arg, time.Microsecond)
if err != nil {
return nil, err
}
if dependsOnContext {
return nil, pgerror.Newf(pgcode.InvalidParameterValue, "relative timestamps are not supported")
}
return ts, nil
},
Info: "Convert a string containing an absolute timestamp to the corresponding timestamp.",
Volatility: tree.VolatilityImmutable,
},
),

// Array functions.

"string_to_array": makeBuiltin(arrayPropsNullableArgs(),
Expand Down

0 comments on commit 5bd05a1

Please sign in to comment.