From 4160bf2b04374c08e19a216b405f5c7dcc1a7e4b Mon Sep 17 00:00:00 2001 From: Annie Pompa Date: Tue, 15 Aug 2023 22:29:42 -0400 Subject: [PATCH] sql: implement datetime builtins 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). --- docs/generated/sql/functions.md | 13 +++ .../logictest/testdata/logic_test/datetime | 99 ++++++++++++++++ pkg/sql/sem/builtins/builtins.go | 106 +++++++++++++++++- pkg/sql/sem/builtins/fixed_oids.go | 5 + 4 files changed, 222 insertions(+), 1 deletion(-) diff --git a/docs/generated/sql/functions.md b/docs/generated/sql/functions.md index 596f1f12ad3e..49d027872c28 100644 --- a/docs/generated/sql/functions.md +++ b/docs/generated/sql/functions.md @@ -521,6 +521,11 @@ significant than element to zero (or one, for day and month)

Compatible elements: millennium, century, decade, year, quarter, month, week, day, hour, minute, second, millisecond, microsecond.

Stable +date_trunc(element: string, input: timestamptz, timezone: string) → timestamptz

Truncates input to precision element in the specified timezone. Sets all fields that are less +significant than element to zero (or one, for day and month)

+

Compatible elements: millennium, century, decade, year, quarter, month, +week, day, hour, minute, second, millisecond, microsecond.

+
Stable experimental_follower_read_timestamp() → timestamptz

Same as follower_read_timestamp. This name is deprecated.

Volatile experimental_strftime(input: date, extract_format: string) → string

From input, extracts and formats the time as identified in extract_format using standard strftime notation (though not all formatting is supported).

@@ -605,6 +610,14 @@ has no relationship with the commit order of concurrent transactions.

and which stays constant throughout the transaction. This timestamp has no relationship with the commit order of concurrent transactions.

Stable +make_date(year: int, month: int, day: int) → date

Create date from year, month, and day fields (negative years signify BC).

+
Immutable +make_timestamp(year: int, month: int, day: int, hour: int, min: int, sec: float) → timestamp

Create timestamp from year, month, day, hour, minute, and seconds fields (negative years signify BC).

+
Immutable +make_timestamptz(year: int, month: int, day: int, hour: int, min: int, sec: float) → timestamptz

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.

+
Stable +make_timestamptz(year: int, month: int, day: int, hour: int, min: int, sec: float, timezone: string) → timestamptz

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.

+
Stable now() → date

Returns the time of the current transaction.

The value is based on a timestamp picked when the transaction starts and which stays constant throughout the transaction. This timestamp diff --git a/pkg/sql/logictest/testdata/logic_test/datetime b/pkg/sql/logictest/testdata/logic_test/datetime index d512a561936d..034076a5578d 100644 --- a/pkg/sql/logictest/testdata/logic_test/datetime +++ b/pkg/sql/logictest/testdata/logic_test/datetime @@ -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 22008 pq: make_timestamptz\(\): the given timezone could not be parsed properly +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 22008 pq: date_trunc\(\): the given timezone could not be parsed properly +SELECT date_trunc('day', '4-02-16 20:38:40+00'::timestamptz, 'No'); + +subtest end diff --git a/pkg/sql/sem/builtins/builtins.go b/pkg/sql/sem/builtins/builtins.go index bd7c889ada1c..0d44b33693b6 100644 --- a/pkg/sql/sem/builtins/builtins.go +++ b/pkg/sql/sem/builtins/builtins.go @@ -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: // @@ -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.New(pgcode.DatetimeFieldOverflow, "the given timezone could not be parsed properly") + } + 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(), @@ -11296,3 +11345,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.New(pgcode.DatetimeFieldOverflow, "the given timezone could not be parsed properly") + } + } + 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, + } +} diff --git a/pkg/sql/sem/builtins/fixed_oids.go b/pkg/sql/sem/builtins/fixed_oids.go index 2f5b196e4528..0d47387f23a0 100644 --- a/pkg/sql/sem/builtins/fixed_oids.go +++ b/pkg/sql/sem/builtins/fixed_oids.go @@ -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