Skip to content

Commit

Permalink
sql: implement datetime builtins
Browse files Browse the repository at this point in the history
Previously, `make_date`, `make_timestamp`, and `make_timestamptz`
built-ins were not implemented. In addition, a new signature for
`date_trunc` was not implemented. This was inadequate because it caused
an incompatibility issue for tools that needed these datetime functions.
To address this, this patch adds said datetime built-ins.

Epic: none
Fixes: #108448

Release note (sql change): Datetime built-ins (make_date,
make_timestamp, and make_timestamptz) are implemented - allowing for
the creation of timestamps, timestamps with time zones, and dates. In
addition, date_trunc now allows for a timestamp to be truncated in a
provided timezone (to a provided precision).
  • Loading branch information
annrpom committed Aug 31, 2023
1 parent 36bd829 commit ba25136
Show file tree
Hide file tree
Showing 4 changed files with 237 additions and 13 deletions.
13 changes: 13 additions & 0 deletions docs/generated/sql/functions.md
Expand Up @@ -521,6 +521,11 @@ significant than <code>element</code> to zero (or one, for day and month)</p>
<p>Compatible elements: millennium, century, decade, year, quarter, month,
week, day, hour, minute, second, millisecond, microsecond.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="date_trunc"></a><code>date_trunc(element: <a href="string.html">string</a>, input: <a href="timestamp.html">timestamptz</a>, timezone: <a href="string.html">string</a>) &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Truncates <code>input</code> to precision <code>element</code> in the specified <code>timezone</code>. Sets all fields that are less
significant than <code>element</code> to zero (or one, for day and month)</p>
<p>Compatible elements: millennium, century, decade, year, quarter, month,
week, day, hour, minute, second, millisecond, microsecond.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="experimental_follower_read_timestamp"></a><code>experimental_follower_read_timestamp() &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Same as follower_read_timestamp. This name is deprecated.</p>
</span></td><td>Volatile</td></tr>
<tr><td><a name="experimental_strftime"></a><code>experimental_strftime(input: <a href="date.html">date</a>, extract_format: <a href="string.html">string</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>From <code>input</code>, extracts and formats the time as identified in <code>extract_format</code> using standard <code>strftime</code> notation (though not all formatting is supported).</p>
Expand Down Expand Up @@ -605,6 +610,14 @@ has no relationship with the commit order of concurrent transactions.</p>
and which stays constant throughout the transaction. This timestamp
has no relationship with the commit order of concurrent transactions.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="make_date"></a><code>make_date(year: <a href="int.html">int</a>, month: <a href="int.html">int</a>, day: <a href="int.html">int</a>) &rarr; <a href="date.html">date</a></code></td><td><span class="funcdesc"><p>Create date from year, month, and day fields (negative years signify BC).</p>
</span></td><td>Immutable</td></tr>
<tr><td><a name="make_timestamp"></a><code>make_timestamp(year: <a href="int.html">int</a>, month: <a href="int.html">int</a>, day: <a href="int.html">int</a>, hour: <a href="int.html">int</a>, min: <a href="int.html">int</a>, sec: <a href="float.html">float</a>) &rarr; <a href="timestamp.html">timestamp</a></code></td><td><span class="funcdesc"><p>Create timestamp from year, month, day, hour, minute, and seconds fields (negative years signify BC).</p>
</span></td><td>Immutable</td></tr>
<tr><td><a name="make_timestamptz"></a><code>make_timestamptz(year: <a href="int.html">int</a>, month: <a href="int.html">int</a>, day: <a href="int.html">int</a>, hour: <a href="int.html">int</a>, min: <a href="int.html">int</a>, sec: <a href="float.html">float</a>) &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Create timestamp with time zone from year, month, day, hour, minute and seconds fields (negative years signify BC). If timezone is not specified, the current time zone is used.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="make_timestamptz"></a><code>make_timestamptz(year: <a href="int.html">int</a>, month: <a href="int.html">int</a>, day: <a href="int.html">int</a>, hour: <a href="int.html">int</a>, min: <a href="int.html">int</a>, sec: <a href="float.html">float</a>, timezone: <a href="string.html">string</a>) &rarr; <a href="timestamp.html">timestamptz</a></code></td><td><span class="funcdesc"><p>Create timestamp with time zone from year, month, day, hour, minute and seconds fields (negative years signify BC). If timezone is not specified, the current time zone is used.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="now"></a><code>now() &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
123 changes: 111 additions & 12 deletions pkg/sql/logictest/testdata/logic_test/datetime
Expand Up @@ -633,9 +633,12 @@ SELECT extract(hours from '2016-02-10 19:46:33.306157519-04'::timestamptz)
----
23

statement error pgcode 22009 pq: date_trunc\(\): negative year value is not valid
SELECT date_trunc('hours', '2016-02-10 19:46:33.306157519 BC'::timestamp);

query ITTBT
SELECT k, element, input, date_trunc(element, input::timestamp) = date_trunc_result, date_trunc(element, input::timestamp)::string
FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
FROM ex WHERE date_trunc_result IS NOT NULL AND input::string NOT LIKE '%BC%' ORDER BY k
----
1 year 2001-04-10 12:04:59 +0000 UTC true 2001-01-01 00:00:00
2 year 2016-02-10 19:46:33.306158 +0000 UTC true 2016-01-01 00:00:00
Expand Down Expand Up @@ -671,15 +674,15 @@ FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
39 microsecond 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33.306158
40 microseconds 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33.306158
45 decade 2001-04-10 12:04:59 +0000 UTC true 2000-01-01 00:00:00
46 decade -2015-02-10 19:46:33.306158 +0000 UTC true 2021-01-01 00:00:00 BC
47 century 2016-02-10 19:46:33.306158 +0000 UTC true 2001-01-01 00:00:00
48 century -0003-02-10 19:46:33.306158 +0000 UTC true 0100-01-01 00:00:00 BC
49 millennium 2016-02-10 19:46:33.306158 +0000 UTC true 2001-01-01 00:00:00
50 millennium -1003-02-10 19:46:33.306158 +0000 UTC true 2000-01-01 00:00:00 BC

statement error pgcode 22009 pq: date_trunc\(\): negative year value is not valid
SELECT date_trunc('hours', '2016-02-10 19:46:33.306157519 BC'::timestamptz);

query IBT
SELECT k, date_trunc(element, input::timestamptz) = date_trunc_result, date_trunc(element, input::timestamptz)::string
FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
FROM ex WHERE date_trunc_result IS NOT NULL AND input::string NOT LIKE '%BC%' ORDER BY k
----
1 true 2001-01-01 00:00:00+00
2 true 2016-01-01 00:00:00+00
Expand Down Expand Up @@ -715,11 +718,8 @@ FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
39 true 2016-02-10 19:46:33.306158+00
40 true 2016-02-10 19:46:33.306158+00
45 true 2000-01-01 00:00:00+00
46 true 2021-01-01 00:00:00+00 BC
47 true 2001-01-01 00:00:00+00
48 true 0100-01-01 00:00:00+00 BC
49 true 2001-01-01 00:00:00+00
50 true 2000-01-01 00:00:00+00 BC

query T
SELECT date_trunc('millennia', '2000-02-10 19:46:33.306157519-04'::timestamptz)::string
Expand All @@ -746,9 +746,12 @@ SELECT date_trunc('hours', '2016-02-10 19:46:33.306157519-04'::timestamptz)::str
----
2016-02-10 23:00:00+00

statement error pgcode 22009 pq: date_trunc\(\): negative year value is not valid
SELECT date_trunc('hours', '2016-02-10 19:46:33.306157519 BC'::date);

query IBT
SELECT k, date_trunc(element, input::date) = date_trunc_result::date, date_trunc(element, input::date)::string
FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
FROM ex WHERE date_trunc_result IS NOT NULL AND input::string NOT LIKE '%BC%' ORDER BY k
----
1 true 2001-01-01 00:00:00+00
2 true 2016-01-01 00:00:00+00
Expand Down Expand Up @@ -784,11 +787,8 @@ FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
39 true 2016-02-10 00:00:00+00
40 true 2016-02-10 00:00:00+00
45 true 2000-01-01 00:00:00+00
46 true 2021-01-01 00:00:00+00 BC
47 true 2001-01-01 00:00:00+00
48 true 0100-01-01 00:00:00+00 BC
49 true 2001-01-01 00:00:00+00
50 true 2000-01-01 00:00:00+00 BC

query T
SELECT (timestamp '2016-02-10 19:46:33.306157519')::string
Expand Down Expand Up @@ -2014,3 +2014,102 @@ SELECT * FROM ex WHERE ROW('1970-01-02 00:00:01.000001-04'::TIMESTAMPTZ) < '1970
query TTTTT
SELECT * FROM ex WHERE ROW('1970-01-03 00:00:01.000001-04'::TIMESTAMPTZ) < ROW('1970-01-02 00:00:01.000001-04');
----

subtest make_date

query T colnames,rowsort
SELECT make_date(2013, 7, 15)::string
----
make_date
2013-07-15

query T colnames,rowsort
SELECT make_date(-2013, 7, 15)
----
make_date
-2013-07-15 00:00:00 +0000 +0000

statement error pgcode 22008 pq: make_date\(\): year value of 0 is not valid
SELECT make_date(0, 11, 11)

subtest end

subtest make_timestamp

query T colnames,rowsort
SELECT make_timestamp(2013, 7, 15, 8, 15, 23.5)::string
----
make_timestamp
2013-07-15 08:15:23.5

query T colnames,rowsort
SELECT make_timestamp(-2013, 7, 15, 8, 15, 23.5)
----
make_timestamp
-2013-07-15 08:15:23.5 +0000 +0000

query T colnames,rowsort
SELECT make_timestamp(2013, 7, 15, 8, 15, 23.5231231244234)::string
----
make_timestamp
2013-07-15 08:15:23.523123

statement error pgcode 22008 pq: make_timestamp\(\): year value of 0 is not valid
SELECT make_timestamp(0, 7, 15, 8, 15, 23.5);

subtest end

subtest make_timestamptz

statement ok
SET TIME ZONE 'EST';

query T colnames,rowsort
SELECT make_timestamptz(2013, 7, 15, 8, 15, 23.5)
----
make_timestamptz
2013-07-15 08:15:23.5 -0500 EST

query T colnames,rowsort
SELECT make_timestamptz(-2013, 7, 15, 8, 15, 23.5)
----
make_timestamptz
-2013-07-15 08:15:23.5 -0500 EST

query T colnames,rowsort
SELECT make_timestamptz(2013, 7, 15, 8, 15, 23.5231231244234)
----
make_timestamptz
2013-07-15 08:15:23.523123 -0500 EST

query T colnames,rowsort
SELECT make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')
----
make_timestamptz
2013-07-15 07:15:23.5 -0500 EST

statement error pgcode 22008 pq: make_timestamptz\(\): year value of 0 is not valid
SELECT make_timestamptz(0, 7, 15, 8, 15, 23.5);

statement error pgcode 22008 pq: make_timestamptz\(\): year value of 0 is not valid
SELECT make_timestamptz(0, 7, 15, 8, 15, 23.5, 'America/New_York');

statement error pgcode 22023 pq: make_timestamptz\(\): could not parse "No" as time zone
SELECT make_timestamptz(0, 7, 15, 8, 15, 23.5, 'No');

subtest end

subtest date_trunc_withtz

query T
SELECT date_trunc('day', '2001-02-16 20:38:40+00'::timestamptz, 'Australia/Sydney')
----
2001-02-16 08:00:00 -0500 EST

statement error pgcode 22008 pq: date_trunc\(\): parsing as type timestamp: field month value 0 is out of range
SELECT date_trunc('day', '0-02-16 20:38:40+00'::timestamptz, 'Australia/Sydney');

statement error pgcode 22023 pq: date_trunc\(\): could not parse "No" as time zone
SELECT date_trunc('day', '4-02-16 20:38:40+00'::timestamptz, 'No');

subtest end
109 changes: 108 additions & 1 deletion pkg/sql/sem/builtins/builtins.go
Expand Up @@ -2497,11 +2497,42 @@ var regularBuiltins = map[string]builtinDefinition{
},
),

"make_date": makeBuiltin(
tree.FunctionProperties{Category: builtinconstants.CategoryDateAndTime},
tree.Overload{
Types: tree.ParamTypes{{Name: "year", Typ: types.Int}, {Name: "month", Typ: types.Int}, {Name: "day", Typ: types.Int}},
ReturnType: tree.FixedReturnType(types.Date),
Fn: func(_ context.Context, evalCtx *eval.Context, args tree.Datums) (tree.Datum, error) {
year := int(tree.MustBeDInt(args[0]))
month := time.Month(int(tree.MustBeDInt(args[1])))
day := int(tree.MustBeDInt(args[2]))
if year == 0 {
return nil, pgerror.New(pgcode.DatetimeFieldOverflow, "year value of 0 is not valid")
}
location := evalCtx.GetLocation()
return tree.NewDDateFromTime(time.Date(year, month, day, 0, 0, 0, 0, location))
},
Info: "Create date from year, month, and day fields (negative years signify BC).",
Volatility: volatility.Immutable,
},
),

"make_timestamp": makeBuiltin(
tree.FunctionProperties{Category: builtinconstants.CategoryDateAndTime},
makeTimestampStatementBuiltinOverload(false /* withOutputTZ */, false /* withInputTZ */),
),

"make_timestamptz": makeBuiltin(
tree.FunctionProperties{Category: builtinconstants.CategoryDateAndTime},
makeTimestampStatementBuiltinOverload(true /* withOutputTZ */, true /* withInputTZ */),
makeTimestampStatementBuiltinOverload(true /* withOutputTZ */, false /* withInputTZ */),
),

// 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,
// numeric, real, and numeric like text inputs by casting them,
// so we support those for compatibility. This gives us the following
// function signatures:
//
Expand Down Expand Up @@ -3005,6 +3036,24 @@ value if you rely on the HLC for accuracy.`,
"week, day, hour, minute, second, millisecond, microsecond.",
Volatility: volatility.Stable,
},
tree.Overload{
Types: tree.ParamTypes{{Name: "element", Typ: types.String}, {Name: "input", Typ: types.TimestampTZ}, {Name: "timezone", Typ: types.String}},
ReturnType: tree.FixedReturnType(types.TimestampTZ),
Fn: func(_ context.Context, _ *eval.Context, args tree.Datums) (tree.Datum, error) {
timeSpan := strings.ToLower(string(tree.MustBeDString(args[0])))
fromTSTZ := tree.MustBeDTimestampTZ(args[1])
location, err := timeutil.TimeZoneStringToLocation(string(tree.MustBeDString(args[2])), timeutil.TimeZoneStringToLocationPOSIXStandard)
if err != nil {
return nil, pgerror.WithCandidateCode(err, pgcode.InvalidParameterValue)
}
return truncateTimestamp(fromTSTZ.Time.In(location), timeSpan)
},
Info: "Truncates `input` to precision `element` in the specified `timezone`. Sets all fields that are less\n" +
"significant than `element` to zero (or one, for day and month)\n\n" +
"Compatible elements: millennium, century, decade, year, quarter, month,\n" +
"week, day, hour, minute, second, millisecond, microsecond.",
Volatility: volatility.Stable,
},
),

"row_to_json": makeBuiltin(jsonProps(),
Expand Down Expand Up @@ -10613,6 +10662,9 @@ func decodeEscape(input string) ([]byte, error) {

func truncateTimestamp(fromTime time.Time, timeSpan string) (*tree.DTimestampTZ, error) {
year := fromTime.Year()
if year < 0 {
return nil, pgerror.New(pgcode.InvalidTimeZoneDisplacementValue, "negative year value is not valid")
}
month := fromTime.Month()
day := fromTime.Day()
hour := fromTime.Hour()
Expand Down Expand Up @@ -11296,3 +11348,58 @@ func bitmaskOp(aStr, bStr string, op func(byte, byte) byte) (*tree.DBitArray, er

return tree.ParseDBitArray(string(buf))
}

func makeTimestampStatementBuiltinOverload(withOutputTZ bool, withInputTZ bool) tree.Overload {
// If we are not creating a timestamp with a timezone, we shouldn't expect an input timezone
if !withOutputTZ && withInputTZ {
panic("Creating a timestamp without a timezone should not have an input timestamp attached to it.")
}
info := "Create timestamp "
vol := volatility.Immutable
typs := tree.ParamTypes{{Name: "year", Typ: types.Int}, {Name: "month", Typ: types.Int}, {Name: "day", Typ: types.Int},
{Name: "hour", Typ: types.Int}, {Name: "min", Typ: types.Int}, {Name: "sec", Typ: types.Float}}
returnTyp := types.Timestamp
if withOutputTZ {
info += "with time zone from year, month, day, hour, minute and seconds fields (negative years signify BC). If " +
"timezone is not specified, the current time zone is used."
returnTyp = types.TimestampTZ
vol = volatility.Stable
if withInputTZ {
typs = append(typs, tree.ParamType{Name: "timezone", Typ: types.String})
}
} else {
info += "from year, month, day, hour, minute, and seconds fields (negative years signify BC)."
}
return tree.Overload{
Types: typs,
ReturnType: tree.FixedReturnType(returnTyp),
Fn: func(_ context.Context, evalCtx *eval.Context, args tree.Datums) (tree.Datum, error) {
year := int(tree.MustBeDInt(args[0]))
month := time.Month(int(tree.MustBeDInt(args[1])))
day := int(tree.MustBeDInt(args[2]))
location := evalCtx.GetLocation()
var err error
if withInputTZ && withOutputTZ {
location, err = timeutil.TimeZoneStringToLocation(string(tree.MustBeDString(args[6])), timeutil.TimeZoneStringToLocationPOSIXStandard)
if err != nil {
return nil, pgerror.WithCandidateCode(err, pgcode.InvalidParameterValue)
}
}
if year == 0 {
return nil, pgerror.New(pgcode.DatetimeFieldOverflow, "year value of 0 is not valid")
}
hour := int(tree.MustBeDInt(args[3]))
min := int(tree.MustBeDInt(args[4]))
sec := float64(tree.MustBeDFloat(args[5]))
truncatedSec := math.Floor(sec)
nsec := math.Mod(sec, truncatedSec) * float64(time.Second)
t := time.Date(year, month, day, hour, min, int(truncatedSec), int(nsec), location)
if withOutputTZ {
return tree.MakeDTimestampTZ(t, time.Microsecond)
}
return tree.MakeDTimestamp(t, time.Microsecond)
},
Info: info,
Volatility: vol,
}
}
5 changes: 5 additions & 0 deletions pkg/sql/sem/builtins/fixed_oids.go
Expand Up @@ -2453,6 +2453,11 @@ var builtinOidsArray = []string{
2482: `bitmask_xor(a: varbit, b: string) -> varbit`,
2483: `bitmask_xor(a: string, b: varbit) -> varbit`,
2484: `oidvectortypes(vector: oidvector) -> string`,
2485: `make_date(year: int, month: int, day: int) -> date`,
2486: `make_timestamp(year: int, month: int, day: int, hour: int, min: int, sec: float) -> timestamp`,
2487: `make_timestamptz(year: int, month: int, day: int, hour: int, min: int, sec: float) -> timestamptz`,
2488: `make_timestamptz(year: int, month: int, day: int, hour: int, min: int, sec: float, timezone: string) -> timestamptz`,
2489: `date_trunc(element: string, input: timestamptz, timezone: string) -> timestamptz`,
}

var builtinOidsBySignature map[string]oid.Oid
Expand Down

0 comments on commit ba25136

Please sign in to comment.