From: Tom Lane Date: Thu, 12 Sep 2024 18:30:29 +0000 (-0400) Subject: Make jsonpath .string() be immutable for datetimes. X-Git-Tag: REL_17_0~39 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=cc4fdfa411fa0cd6b27563c37c096bf76120659f;p=thirdparty%2Fpostgresql.git Make jsonpath .string() be immutable for datetimes. Discussion of commit ed055d249 revealed that we don't actually want jsonpath's .string() method to depend on DateStyle, nor TimeZone either, because the non-"_tz" jsonpath functions are supposed to be immutable. Potentially we could allow a TimeZone dependency in the "_tz" variants, but it seems better to just uniformly define this method as returning the same string that jsonb text output would do. That's easier to implement too, saving a couple dozen lines. Patch by me, per complaint from Peter Eisentraut. Back-patch to v17 where this feature came in (in 66ea94e8e). Also back-patch ed055d249 to provide test cases. Discussion: https://postgr.es/m/5e8879d0-a3c8-4be2-950f-d83aa2af953a@eisentraut.org --- diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 6b2759e25a1..b51dcfd2b4b 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -17965,15 +17965,16 @@ ERROR: jsonpath member accessor can only be applied to an object string - String value converted from a JSON boolean, number, string, or datetime + String value converted from a JSON boolean, number, string, or + datetime jsonb_path_query_array('[1.23, "xyz", false]', '$[*].string()') ["1.23", "xyz", "false"] - jsonb_path_query('"2023-08-15"', '$.datetime().string()') - "2023-08-15" + jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()') + "2023-08-15T12:34:56" @@ -18054,7 +18055,9 @@ ERROR: jsonpath member accessor can only be applied to an object decimal - Rounded decimal value converted from a JSON number or string. precision and scale must be integer values. + Rounded decimal value converted from a JSON number or string + (precision and scale must be + integer values) jsonb_path_query('1234.5678', '$.decimal(6, 2)') @@ -18156,7 +18159,7 @@ ERROR: jsonpath member accessor can only be applied to an object Time without time zone value converted from a string, with fractional - seconds adjusted to the given precision. + seconds adjusted to the given precision jsonb_path_query('"12:34:56.789"', '$.time(2)') @@ -18185,7 +18188,7 @@ ERROR: jsonpath member accessor can only be applied to an object Time with time zone value converted from a string, with fractional - seconds adjusted to the given precision. + seconds adjusted to the given precision jsonb_path_query('"12:34:56.789 +05:30"', '$.time_tz(2)') @@ -18214,7 +18217,7 @@ ERROR: jsonpath member accessor can only be applied to an object Timestamp without time zone value converted from a string, with - fractional seconds adjusted to the given precision. + fractional seconds adjusted to the given precision jsonb_path_query('"2023-08-15 12:34:56.789"', '$.timestamp(2)') @@ -18243,7 +18246,7 @@ ERROR: jsonpath member accessor can only be applied to an object Timestamp with time zone value converted from a string, with fractional - seconds adjusted to the given precision. + seconds adjusted to the given precision jsonb_path_query('"2023-08-15 12:34:56.789 +05:30"', '$.timestamp_tz(2)') diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c index e569c7efb83..1184cba983a 100644 --- a/src/backend/utils/adt/jsonpath_exec.c +++ b/src/backend/utils/adt/jsonpath_exec.c @@ -72,6 +72,7 @@ #include "utils/datetime.h" #include "utils/float.h" #include "utils/formatting.h" +#include "utils/json.h" #include "utils/jsonpath.h" #include "utils/lsyscache.h" #include "utils/memutils.h" @@ -1629,32 +1630,13 @@ executeItemOptUnwrapTarget(JsonPathExecContext *cxt, JsonPathItem *jsp, break; case jbvDatetime: { - switch (jb->val.datetime.typid) - { - case DATEOID: - tmp = DatumGetCString(DirectFunctionCall1(date_out, - jb->val.datetime.value)); - break; - case TIMEOID: - tmp = DatumGetCString(DirectFunctionCall1(time_out, - jb->val.datetime.value)); - break; - case TIMETZOID: - tmp = DatumGetCString(DirectFunctionCall1(timetz_out, - jb->val.datetime.value)); - break; - case TIMESTAMPOID: - tmp = DatumGetCString(DirectFunctionCall1(timestamp_out, - jb->val.datetime.value)); - break; - case TIMESTAMPTZOID: - tmp = DatumGetCString(DirectFunctionCall1(timestamptz_out, - jb->val.datetime.value)); - break; - default: - elog(ERROR, "unrecognized SQL/JSON datetime type oid: %u", - jb->val.datetime.typid); - } + char buf[MAXDATELEN + 1]; + + JsonEncodeDateTime(buf, + jb->val.datetime.value, + jb->val.datetime.typid, + &jb->val.datetime.tz); + tmp = pstrdup(buf); } break; case jbvNull: diff --git a/src/test/regress/expected/horology.out b/src/test/regress/expected/horology.out index 241713cc51e..58da26ab0e1 100644 --- a/src/test/regress/expected/horology.out +++ b/src/test/regress/expected/horology.out @@ -1,13 +1,18 @@ -- -- HOROLOGY -- -SET DateStyle = 'Postgres, MDY'; -SHOW TimeZone; -- Many of these tests depend on the prevailing setting +SHOW TimeZone; -- Many of these tests depend on the prevailing settings TimeZone ---------- PST8PDT (1 row) +SHOW DateStyle; + DateStyle +--------------- + Postgres, MDY +(1 row) + -- -- Test various input formats -- diff --git a/src/test/regress/expected/jsonb_jsonpath.out b/src/test/regress/expected/jsonb_jsonpath.out index b5bcece94e3..57c117ea580 100644 --- a/src/test/regress/expected/jsonb_jsonpath.out +++ b/src/test/regress/expected/jsonb_jsonpath.out @@ -2586,15 +2586,6 @@ select jsonb_path_query('[2, true]', '$.string()'); "true" (2 rows) -select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); -ERROR: cannot convert value from timestamptz to timestamp without time zone usage -HINT: Use *_tz() function for time zone support. -select jsonb_path_query_tz('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); -- should work - jsonb_path_query_tz ----------------------------- - "Tue Aug 15 00:04:56 2023" -(1 row) - select jsonb_path_query_array('[1.23, "yes", false]', '$[*].string()'); jsonb_path_query_array -------------------------- @@ -2607,6 +2598,77 @@ select jsonb_path_query_array('[1.23, "yes", false]', '$[*].string().type()'); ["string", "string", "string"] (1 row) +select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); +ERROR: cannot convert value from timestamptz to timestamp without time zone usage +HINT: Use *_tz() function for time zone support. +select jsonb_path_query_tz('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); -- should work + jsonb_path_query_tz +----------------------- + "2023-08-15T00:04:56" +(1 row) + +select jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp_tz().string()'); +ERROR: cannot convert value from timestamp to timestamptz without time zone usage +HINT: Use *_tz() function for time zone support. +select jsonb_path_query_tz('"2023-08-15 12:34:56"', '$.timestamp_tz().string()'); -- should work + jsonb_path_query_tz +----------------------------- + "2023-08-15T12:34:56-07:00" +(1 row) + +select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp_tz().string()'); + jsonb_path_query +----------------------------- + "2023-08-15T12:34:56+05:30" +(1 row) + +select jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()'); + jsonb_path_query +----------------------- + "2023-08-15T12:34:56" +(1 row) + +select jsonb_path_query('"12:34:56 +5:30"', '$.time_tz().string()'); + jsonb_path_query +------------------ + "12:34:56+05:30" +(1 row) + +select jsonb_path_query_tz('"12:34:56"', '$.time_tz().string()'); + jsonb_path_query_tz +--------------------- + "12:34:56-07:00" +(1 row) + +select jsonb_path_query('"12:34:56"', '$.time().string()'); + jsonb_path_query +------------------ + "12:34:56" +(1 row) + +select jsonb_path_query('"2023-08-15"', '$.date().string()'); + jsonb_path_query +------------------ + "2023-08-15" +(1 row) + +-- .string() does not react to timezone or datestyle +begin; +set local timezone = 'UTC'; +set local datestyle = 'German'; +select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp_tz().string()'); + jsonb_path_query +----------------------------- + "2023-08-15T12:34:56+05:30" +(1 row) + +select jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()'); + jsonb_path_query +----------------------- + "2023-08-15T12:34:56" +(1 row) + +rollback; -- Test .time() select jsonb_path_query('null', '$.time()'); ERROR: jsonpath item method .time() can only be applied to a string diff --git a/src/test/regress/sql/horology.sql b/src/test/regress/sql/horology.sql index e5cf12ff63d..0fe3c783e61 100644 --- a/src/test/regress/sql/horology.sql +++ b/src/test/regress/sql/horology.sql @@ -1,9 +1,9 @@ -- -- HOROLOGY -- -SET DateStyle = 'Postgres, MDY'; -SHOW TimeZone; -- Many of these tests depend on the prevailing setting +SHOW TimeZone; -- Many of these tests depend on the prevailing settings +SHOW DateStyle; -- -- Test various input formats diff --git a/src/test/regress/sql/jsonb_jsonpath.sql b/src/test/regress/sql/jsonb_jsonpath.sql index 5e14f7759bb..c647af55e94 100644 --- a/src/test/regress/sql/jsonb_jsonpath.sql +++ b/src/test/regress/sql/jsonb_jsonpath.sql @@ -587,10 +587,26 @@ select jsonb_path_query('1234', '$.string()'); select jsonb_path_query('true', '$.string()'); select jsonb_path_query('1234', '$.string().type()'); select jsonb_path_query('[2, true]', '$.string()'); -select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); -select jsonb_path_query_tz('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); -- should work select jsonb_path_query_array('[1.23, "yes", false]', '$[*].string()'); select jsonb_path_query_array('[1.23, "yes", false]', '$[*].string().type()'); +select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); +select jsonb_path_query_tz('"2023-08-15 12:34:56 +5:30"', '$.timestamp().string()'); -- should work +select jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp_tz().string()'); +select jsonb_path_query_tz('"2023-08-15 12:34:56"', '$.timestamp_tz().string()'); -- should work +select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp_tz().string()'); +select jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()'); +select jsonb_path_query('"12:34:56 +5:30"', '$.time_tz().string()'); +select jsonb_path_query_tz('"12:34:56"', '$.time_tz().string()'); +select jsonb_path_query('"12:34:56"', '$.time().string()'); +select jsonb_path_query('"2023-08-15"', '$.date().string()'); + +-- .string() does not react to timezone or datestyle +begin; +set local timezone = 'UTC'; +set local datestyle = 'German'; +select jsonb_path_query('"2023-08-15 12:34:56 +5:30"', '$.timestamp_tz().string()'); +select jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()'); +rollback; -- Test .time() select jsonb_path_query('null', '$.time()');