Support for ISO 8601 in the jsonpath .datetime() method
authorAlexander Korotkov <[email protected]>
Tue, 29 Sep 2020 08:41:46 +0000 (11:41 +0300)
committerAlexander Korotkov <[email protected]>
Tue, 29 Sep 2020 09:00:04 +0000 (12:00 +0300)
The SQL standard doesn't require jsonpath .datetime() method to support the
ISO 8601 format.  But our to_json[b]() functions convert timestamps to text in
the ISO 8601 format in the sake of compatibility with javascript.  So, we add
support of the  ISO 8601 to the jsonpath .datetime() in the sake compatibility
with to_json[b]().

The standard mode of datetime parsing currently supports just template patterns
and separators in the format string.  In order to implement ISO 8601, we have to
add support of the format string double quotes to the standard parsing mode.

Discussion: https://postgr.es/m/94321be0-cc96-1a81-b6df-796f437f7c66%40postgrespro.ru
Author: Nikita Glukhov, revised by me
Backpatch-through: 13

src/backend/utils/adt/formatting.c
src/backend/utils/adt/jsonpath_exec.c
src/test/regress/expected/jsonb_jsonpath.out
src/test/regress/sql/jsonb_jsonpath.sql

index f9aa968f0985f65b26b6ba270349ee6bf79ffa99..b91ff7bb80366b207c42618d10af17d9a57f01ef 100644 (file)
@@ -1381,10 +1381,12 @@ parse_format(FormatNode *node, const char *str, const KeyWord *kw,
        {
            int         chlen;
 
-           if (flags & STD_FLAG)
+           if ((flags & STD_FLAG) && *str != '"')
            {
                /*
-                * Standard mode, allow only following separators: "-./,':; "
+                * Standard mode, allow only following separators: "-./,':; ".
+                * However, we support double quotes even in standard mode
+                * (see below).  This is our extension of standard mode.
                 */
                if (strchr("-./,':; ", *str) == NULL)
                    ereport(ERROR,
@@ -3346,7 +3348,19 @@ DCH_from_char(FormatNode *node, const char *in, TmFromChar *out,
            }
            else
            {
-               s += pg_mblen(s);
+               int         chlen = pg_mblen(s);
+
+               /*
+                * Standard mode requires strict match of format characters.
+                */
+               if (std && n->type == NODE_TYPE_CHAR &&
+                   strncmp(s, n->character, chlen) != 0)
+                   RETURN_ERROR(ereport(ERROR,
+                                        (errcode(ERRCODE_INVALID_DATETIME_FORMAT),
+                                         errmsg("unmatched format character \"%s\"",
+                                                n->character))));
+
+               s += chlen;
            }
            continue;
        }
index 31b88d67416681124744531caa634b58671ba66b..28be845770a6123602b906742617dde06256e5ae 100644 (file)
@@ -1833,6 +1833,9 @@ executeDateTimeMethod(JsonPathExecContext *cxt, JsonPathItem *jsp,
        /*
         * According to SQL/JSON standard enumerate ISO formats for: date,
         * timetz, time, timestamptz, timestamp.
+        *
+        * We also support ISO 8601 for timestamps, because to_json[b]()
+        * functions use this format.
         */
        static const char *fmt_str[] =
        {
@@ -1842,7 +1845,10 @@ executeDateTimeMethod(JsonPathExecContext *cxt, JsonPathItem *jsp,
            "HH24:MI:SS",
            "yyyy-mm-dd HH24:MI:SSTZH:TZM",
            "yyyy-mm-dd HH24:MI:SSTZH",
-           "yyyy-mm-dd HH24:MI:SS"
+           "yyyy-mm-dd HH24:MI:SS",
+           "yyyy-mm-dd\"T\"HH24:MI:SSTZH:TZM",
+           "yyyy-mm-dd\"T\"HH24:MI:SSTZH",
+           "yyyy-mm-dd\"T\"HH24:MI:SS"
        };
 
        /* cache for format texts */
index 31d6f05a7c2000360c4846483fe42c0c182f7652..508ddd797ed59e40c51d3d7417b5e396ea4a27b2 100644 (file)
@@ -1722,6 +1722,16 @@ select jsonb_path_query('"12:34:56 +05:20"', '$.datetime("HH24:MI:SS TZH:TZM").t
  "time with time zone"
 (1 row)
 
+select jsonb_path_query('"10-03-2017T12:34:56"', '$.datetime("dd-mm-yyyy\"T\"HH24:MI:SS")');
+   jsonb_path_query    
+-----------------------
+ "2017-03-10T12:34:56"
+(1 row)
+
+select jsonb_path_query('"10-03-2017t12:34:56"', '$.datetime("dd-mm-yyyy\"T\"HH24:MI:SS")');
+ERROR:  unmatched format character "T"
+select jsonb_path_query('"10-03-2017 12:34:56"', '$.datetime("dd-mm-yyyy\"T\"HH24:MI:SS")');
+ERROR:  unmatched format character "T"
 set time zone '+00';
 select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")');
    jsonb_path_query    
@@ -1901,6 +1911,15 @@ select jsonb_path_query('"2017-03-10 12:34:56+3:10"', '$.datetime()');
  "2017-03-10T12:34:56+03:10"
 (1 row)
 
+select jsonb_path_query('"2017-03-10T12:34:56+3:10"', '$.datetime()');
+      jsonb_path_query       
+-----------------------------
+ "2017-03-10T12:34:56+03:10"
+(1 row)
+
+select jsonb_path_query('"2017-03-10t12:34:56+3:10"', '$.datetime()');
+ERROR:  datetime format is not recognized: "2017-03-10t12:34:56+3:10"
+HINT:  Use a datetime template argument to specify the input data format.
 select jsonb_path_query('"12:34:56"', '$.datetime().type()');
      jsonb_path_query     
 --------------------------
index dc25ceb283dffdb5d467a283983dedfb2b79bb0a..60f73cb05906c546ed847e8f937f859c8d37d4bc 100644 (file)
@@ -368,6 +368,10 @@ select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH2
 select jsonb_path_query('"12:34:56"', '$.datetime("HH24:MI:SS").type()');
 select jsonb_path_query('"12:34:56 +05:20"', '$.datetime("HH24:MI:SS TZH:TZM").type()');
 
+select jsonb_path_query('"10-03-2017T12:34:56"', '$.datetime("dd-mm-yyyy\"T\"HH24:MI:SS")');
+select jsonb_path_query('"10-03-2017t12:34:56"', '$.datetime("dd-mm-yyyy\"T\"HH24:MI:SS")');
+select jsonb_path_query('"10-03-2017 12:34:56"', '$.datetime("dd-mm-yyyy\"T\"HH24:MI:SS")');
+
 set time zone '+00';
 
 select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")');
@@ -408,6 +412,8 @@ select jsonb_path_query('"2017-03-10 12:34:56+3"', '$.datetime().type()');
 select jsonb_path_query('"2017-03-10 12:34:56+3"', '$.datetime()');
 select jsonb_path_query('"2017-03-10 12:34:56+3:10"', '$.datetime().type()');
 select jsonb_path_query('"2017-03-10 12:34:56+3:10"', '$.datetime()');
+select jsonb_path_query('"2017-03-10T12:34:56+3:10"', '$.datetime()');
+select jsonb_path_query('"2017-03-10t12:34:56+3:10"', '$.datetime()');
 select jsonb_path_query('"12:34:56"', '$.datetime().type()');
 select jsonb_path_query('"12:34:56"', '$.datetime()');
 select jsonb_path_query('"12:34:56+3"', '$.datetime().type()');