Implement jsonpath .datetime() method

This commit implements jsonpath .datetime() method as it's specified in
SQL/JSON standard.  There are no-argument and single-argument versions of
this method.  No-argument version selects first of ISO datetime formats
matching input string.  Single-argument version accepts template string as
its argument.

Additionally to .datetime() method itself this commit also implements
comparison ability of resulting date and time values.  There is some difficulty
because exising jsonb_path_*() functions are immutable, while comparison of
timezoned and non-timezoned types involves current timezone.  At first, current
timezone could be changes in session.  Moreover, timezones themselves are not
immutable and could be updated.  This is why we let existing immutable functions
throw errors on such non-immutable comparison.  In the same time this commit
provides jsonb_path_*_tz() functions which are stable and support operations
involving timezones.  As new functions are added to the system catalog,
catversion is bumped.

Support of .datetime() method was the only blocker prevents T832 from being
marked as supported.  sql_features.txt is updated correspondingly.

Extracted from original patch by Nikita Glukhov, Teodor Sigaev, Oleg Bartunov.
Heavily revised by me.  Comments were adjusted by Liudmila Mantrova.

Discussion: https://postgr.es/m/fcc6fc6a-b497-f39a-923d-aa34d0c588e8%402ndQuadrant.com
Discussion: https://postgr.es/m/CAPpHfdsZgYEra_PeCLGNoXOWYx6iU-S3wF8aX0ObQUcZU%2B4XTw%40mail.gmail.com
Author: Alexander Korotkov, Nikita Glukhov, Teodor Sigaev, Oleg Bartunov, Liudmila Mantrova
Reviewed-by: Anastasia Lubennikova, Peter Eisentraut
This commit is contained in:
Alexander Korotkov 2019-09-25 21:54:14 +03:00
parent 6dda292d4d
commit bffe1bd684
15 changed files with 1355 additions and 45 deletions

View File

@ -11910,16 +11910,6 @@ table2-mapping
</para>
<itemizedlist>
<listitem>
<para>
<literal>.datetime()</literal> item method is not implemented yet
mainly because immutable <type>jsonpath</type> functions and operators
cannot reference session timezone, which is used in some datetime
operations. Datetime support will be added to <type>jsonpath</type>
in future versions of <productname>PostgreSQL</productname>.
</para>
</listitem>
<listitem>
<para>
A path expression can be a Boolean predicate, although the SQL/JSON
@ -12190,6 +12180,20 @@ table2-mapping
<entry><literal>$.z.abs()</literal></entry>
<entry><literal>0.3</literal></entry>
</row>
<row>
<entry><literal>datetime()</literal></entry>
<entry>Date/time value converted from a string</entry>
<entry><literal>["2015-8-1", "2015-08-12"]</literal></entry>
<entry><literal>$[*] ? (@.datetime() &lt; "2015-08-2". datetime())</literal></entry>
<entry><literal>2015-8-1</literal></entry>
</row>
<row>
<entry><literal>datetime(<replaceable>template</replaceable>)</literal></entry>
<entry>Date/time value converted from a string using the specified template</entry>
<entry><literal>["12:30", "18:40"]</literal></entry>
<entry><literal>$[*].datetime("HH24:MI")</literal></entry>
<entry><literal>"12:30:00", "18:40:00"</literal></entry>
</row>
<row>
<entry><literal>keyvalue()</literal></entry>
<entry>
@ -12207,6 +12211,37 @@ table2-mapping
</tgroup>
</table>
<note>
<para>
The result type of <literal>datetime()</literal> and
<literal>datetime(<replaceable>template</replaceable>)</literal>
methods can be <type>date</type>, <type>timetz</type>, <type>time</type>,
<type>timestamptz</type>, or <type>timestamp</type>.
Both methods determine the result type dynamically.
</para>
<para>
The <literal>datetime()</literal> method sequentially tries ISO formats
for <type>date</type>, <type>timetz</type>, <type>time</type>,
<type>timestamptz</type>, and <type>timestamp</type>. It stops on
the first matching format and the corresponding data type.
</para>
<para>
The <literal>datetime(<replaceable>template</replaceable>)</literal>
method determines the result type by the provided template string.
</para>
<para>
The <literal>datetime()</literal> and
<literal>datetime(<replaceable>template</replaceable>)</literal> methods
use the same parsing rules as <literal>to_timestamp</literal> SQL
function does (see <xref linkend="functions-formatting"/>) with three
exceptions. At first, these methods doesn't allow unmatched template
patterns. At second, only following separators are allowed in the
template string: minus sign, period, solidus, comma, apostrophe,
semicolon, colon and space. At third, separators in the template string
must exactly match the input string.
</para>
</note>
<table id="functions-sqljson-filter-ex-table">
<title><type>jsonpath</type> Filter Expression Elements</title>
<tgroup cols="5">
@ -12350,6 +12385,15 @@ table2-mapping
</tbody>
</tgroup>
</table>
<note>
<para>
When different date/time values are compared, an implicit cast is
applied. A <type>date</type> value can be cast to <type>timestamp</type>
or <type>timestamptz</type>, <type>timestamp</type> can be cast to
<type>timestamptz</type>, and <type>time</type> &mdash; to <type>timetz</type>.
</para>
</note>
</sect3>
</sect2>
@ -12582,7 +12626,7 @@ table2-mapping
<para>
The <literal>@?</literal> and <literal>@@</literal> operators suppress
the following errors: lacking object field or array element, unexpected
JSON item type, and numeric errors.
JSON item type, datetime and numeric errors.
This behavior might be helpful while searching over JSON document
collections of varying structure.
</para>
@ -12851,18 +12895,33 @@ table2-mapping
<indexterm>
<primary>jsonb_path_exists</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_exists_tz</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_match</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_match_tz</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_query</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_query_tz</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_query_array</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_query_array_tz</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_query_first</primary>
</indexterm>
<indexterm>
<primary>jsonb_path_query_first_tz</primary>
</indexterm>
<table id="functions-json-processing-table">
<title>JSON Processing Functions</title>
@ -13202,6 +13261,9 @@ table2-mapping
<para><literal>
jsonb_path_exists(target jsonb, path jsonpath [, vars jsonb [, silent bool]])
</literal></para>
<para><literal>
jsonb_path_exists_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
</entry>
<entry><type>boolean</type></entry>
<entry>
@ -13222,6 +13284,9 @@ table2-mapping
<para><literal>
jsonb_path_match(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
<para><literal>
jsonb_path_match_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
</entry>
<entry><type>boolean</type></entry>
<entry>
@ -13243,6 +13308,9 @@ table2-mapping
<para><literal>
jsonb_path_query(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
<para><literal>
jsonb_path_query_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
</entry>
<entry><type>setof jsonb</type></entry>
<entry>
@ -13271,6 +13339,9 @@ table2-mapping
<para><literal>
jsonb_path_query_array(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
<para><literal>
jsonb_path_query_array_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
</entry>
<entry><type>jsonb</type></entry>
<entry>
@ -13291,6 +13362,9 @@ table2-mapping
<para><literal>
jsonb_path_query_first(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
<para><literal>
jsonb_path_query_first_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
</literal></para>
</entry>
<entry><type>jsonb</type></entry>
<entry>
@ -13433,11 +13507,8 @@ table2-mapping
<note>
<para>
The <literal>jsonb_path_exists</literal>, <literal>jsonb_path_match</literal>,
<literal>jsonb_path_query</literal>, <literal>jsonb_path_query_array</literal>, and
<literal>jsonb_path_query_first</literal>
functions have optional <literal>vars</literal> and <literal>silent</literal>
arguments.
The <literal>jsonb_path_*</literal> functions have optional
<literal>vars</literal> and <literal>silent</literal> arguments.
</para>
<para>
If the <parameter>vars</parameter> argument is specified, it provides an
@ -13451,6 +13522,20 @@ table2-mapping
</para>
</note>
<note>
<para>
Some of the <literal>jsonb_path_*</literal> functions have the
<literal>_tz</literal> suffix. These functions have been implemented to
support comparison of date/time values that involves implicit
timezone-aware casts. Since operations with time zones are not immutable,
these functions are qualified as stable. Their counterparts without the
suffix do not support such casts, so they are immutable and can be used for
such use-cases as expression indexes
(see <xref linkend="indexes-expressional"/>). There is no difference
between these functions for other <type>jsonpath</type> operations.
</para>
</note>
<para>
See also <xref linkend="functions-aggregate"/> for the aggregate
function <function>json_agg</function> which aggregates record

View File

@ -544,7 +544,7 @@ T828 JSON_QUERY NO
T829 JSON_QUERY: array wrapper options NO
T830 Enforcing unique keys in SQL/JSON constructor functions NO
T831 SQL/JSON path language: strict mode YES
T832 SQL/JSON path language: item method NO datetime() not yet implemented
T832 SQL/JSON path language: item method YES
T833 SQL/JSON path language: multiple subscripts YES
T834 SQL/JSON path language: wildcard member accessor YES
T835 SQL/JSON path language: filter expressions YES

View File

@ -1287,6 +1287,46 @@ LANGUAGE INTERNAL
STRICT IMMUTABLE PARALLEL SAFE
AS 'jsonb_path_query_first';
CREATE OR REPLACE FUNCTION
jsonb_path_exists_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
silent boolean DEFAULT false)
RETURNS boolean
LANGUAGE INTERNAL
STRICT STABLE PARALLEL SAFE
AS 'jsonb_path_exists_tz';
CREATE OR REPLACE FUNCTION
jsonb_path_match_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
silent boolean DEFAULT false)
RETURNS boolean
LANGUAGE INTERNAL
STRICT STABLE PARALLEL SAFE
AS 'jsonb_path_match_tz';
CREATE OR REPLACE FUNCTION
jsonb_path_query_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
silent boolean DEFAULT false)
RETURNS SETOF jsonb
LANGUAGE INTERNAL
STRICT STABLE PARALLEL SAFE
AS 'jsonb_path_query_tz';
CREATE OR REPLACE FUNCTION
jsonb_path_query_array_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
silent boolean DEFAULT false)
RETURNS jsonb
LANGUAGE INTERNAL
STRICT STABLE PARALLEL SAFE
AS 'jsonb_path_query_array_tz';
CREATE OR REPLACE FUNCTION
jsonb_path_query_first_tz(target jsonb, path jsonpath, vars jsonb DEFAULT '{}',
silent boolean DEFAULT false)
RETURNS jsonb
LANGUAGE INTERNAL
STRICT STABLE PARALLEL SAFE
AS 'jsonb_path_query_first_tz';
--
-- The default permissions for functions mean that anyone can execute them.
-- A number of functions shouldn't be executable by just anyone, but rather

View File

@ -337,12 +337,14 @@ flattenJsonPathParseItem(StringInfo buf, JsonPathParseItem *item,
case jpiPlus:
case jpiMinus:
case jpiExists:
case jpiDatetime:
{
int32 arg = reserveSpaceForItemPointer(buf);
chld = flattenJsonPathParseItem(buf, item->value.arg,
nestingLevel + argNestingLevel,
insideArraySubscript);
chld = !item->value.arg ? pos :
flattenJsonPathParseItem(buf, item->value.arg,
nestingLevel + argNestingLevel,
insideArraySubscript);
*(int32 *) (buf->data + arg) = chld - pos;
}
break;
@ -692,6 +694,15 @@ printJsonPathItem(StringInfo buf, JsonPathItem *v, bool inKey,
case jpiDouble:
appendBinaryStringInfo(buf, ".double()", 9);
break;
case jpiDatetime:
appendBinaryStringInfo(buf, ".datetime(", 10);
if (v->content.arg)
{
jspGetArg(v, &elem);
printJsonPathItem(buf, &elem, false, false);
}
appendStringInfoChar(buf, ')');
break;
case jpiKeyValue:
appendBinaryStringInfo(buf, ".keyvalue()", 11);
break;
@ -754,6 +765,8 @@ jspOperationName(JsonPathItemType type)
return "floor";
case jpiCeiling:
return "ceiling";
case jpiDatetime:
return "datetime";
default:
elog(ERROR, "unrecognized jsonpath item type: %d", type);
return NULL;
@ -889,6 +902,7 @@ jspInitByBuffer(JsonPathItem *v, char *base, int32 pos)
case jpiPlus:
case jpiMinus:
case jpiFilter:
case jpiDatetime:
read_int32(v->content.arg, base, pos);
break;
case jpiIndexArray:
@ -913,7 +927,8 @@ jspGetArg(JsonPathItem *v, JsonPathItem *a)
v->type == jpiIsUnknown ||
v->type == jpiExists ||
v->type == jpiPlus ||
v->type == jpiMinus);
v->type == jpiMinus ||
v->type == jpiDatetime);
jspInitByBuffer(a, v->base, v->content.arg);
}
@ -961,6 +976,7 @@ jspGetNext(JsonPathItem *v, JsonPathItem *a)
v->type == jpiFloor ||
v->type == jpiCeiling ||
v->type == jpiDouble ||
v->type == jpiDatetime ||
v->type == jpiKeyValue ||
v->type == jpiStartsWith);

View File

@ -66,6 +66,7 @@
#include "miscadmin.h"
#include "regex/regex.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/datum.h"
#include "utils/formatting.h"
#include "utils/float.h"
@ -107,6 +108,7 @@ typedef struct JsonPathExecContext
* ignored */
bool throwErrors; /* with "false" all suppressible errors are
* suppressed */
bool useTz;
} JsonPathExecContext;
/* Context for LIKE_REGEX execution. */
@ -173,7 +175,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
Jsonb *json, bool throwErrors, JsonValueList *result);
Jsonb *json, bool throwErrors,
JsonValueList *result, bool useTz);
static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
JsonPathItem *jsp, JsonbValue *jb, JsonValueList *found);
static JsonPathExecResult executeItemOptUnwrapTarget(JsonPathExecContext *cxt,
@ -214,6 +217,8 @@ static JsonPathBool executeLikeRegex(JsonPathItem *jsp, JsonbValue *str,
static JsonPathExecResult executeNumericItemMethod(JsonPathExecContext *cxt,
JsonPathItem *jsp, JsonbValue *jb, bool unwrap, PGFunction func,
JsonValueList *found);
static JsonPathExecResult executeDateTimeMethod(JsonPathExecContext *cxt, JsonPathItem *jsp,
JsonbValue *jb, JsonValueList *found);
static JsonPathExecResult executeKeyValueMethod(JsonPathExecContext *cxt,
JsonPathItem *jsp, JsonbValue *jb, JsonValueList *found);
static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
@ -225,7 +230,8 @@ static void getJsonPathVariable(JsonPathExecContext *cxt,
static int JsonbArraySize(JsonbValue *jb);
static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
JsonbValue *rv, void *p);
static JsonPathBool compareItems(int32 op, JsonbValue *jb1, JsonbValue *jb2);
static JsonPathBool compareItems(int32 op, JsonbValue *jb1, JsonbValue *jb2,
bool useTz);
static int compareNumeric(Numeric a, Numeric b);
static JsonbValue *copyJsonbValue(JsonbValue *src);
static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
@ -246,6 +252,8 @@ static JsonbValue *JsonbInitBinary(JsonbValue *jbv, Jsonb *jb);
static int JsonbType(JsonbValue *jb);
static JsonbValue *getScalar(JsonbValue *scalar, enum jbvType type);
static JsonbValue *wrapItemsInArray(const JsonValueList *items);
static int compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
bool useTz, bool *have_error);
/****************** User interface to JsonPath executor ********************/
@ -261,8 +269,8 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
* SQL/JSON. Regarding jsonb_path_match(), this function doesn't have
* an analogy in SQL/JSON, so we define its behavior on our own.
*/
Datum
jsonb_path_exists(PG_FUNCTION_ARGS)
static Datum
jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
{
Jsonb *jb = PG_GETARG_JSONB_P(0);
JsonPath *jp = PG_GETARG_JSONPATH_P(1);
@ -276,7 +284,7 @@ jsonb_path_exists(PG_FUNCTION_ARGS)
silent = PG_GETARG_BOOL(3);
}
res = executeJsonPath(jp, vars, jb, !silent, NULL);
res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
PG_FREE_IF_COPY(jb, 0);
PG_FREE_IF_COPY(jp, 1);
@ -287,6 +295,18 @@ jsonb_path_exists(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(res == jperOk);
}
Datum
jsonb_path_exists(PG_FUNCTION_ARGS)
{
return jsonb_path_exists_internal(fcinfo, false);
}
Datum
jsonb_path_exists_tz(PG_FUNCTION_ARGS)
{
return jsonb_path_exists_internal(fcinfo, true);
}
/*
* jsonb_path_exists_opr
* Implementation of operator "jsonb @? jsonpath" (2-argument version of
@ -296,7 +316,7 @@ Datum
jsonb_path_exists_opr(PG_FUNCTION_ARGS)
{
/* just call the other one -- it can handle both cases */
return jsonb_path_exists(fcinfo);
return jsonb_path_exists_internal(fcinfo, false);
}
/*
@ -304,8 +324,8 @@ jsonb_path_exists_opr(PG_FUNCTION_ARGS)
* Returns jsonpath predicate result item for the specified jsonb value.
* See jsonb_path_exists() comment for details regarding error handling.
*/
Datum
jsonb_path_match(PG_FUNCTION_ARGS)
static Datum
jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
{
Jsonb *jb = PG_GETARG_JSONB_P(0);
JsonPath *jp = PG_GETARG_JSONPATH_P(1);
@ -319,7 +339,7 @@ jsonb_path_match(PG_FUNCTION_ARGS)
silent = PG_GETARG_BOOL(3);
}
(void) executeJsonPath(jp, vars, jb, !silent, &found);
(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
PG_FREE_IF_COPY(jb, 0);
PG_FREE_IF_COPY(jp, 1);
@ -343,6 +363,18 @@ jsonb_path_match(PG_FUNCTION_ARGS)
PG_RETURN_NULL();
}
Datum
jsonb_path_match(PG_FUNCTION_ARGS)
{
return jsonb_path_match_internal(fcinfo, false);
}
Datum
jsonb_path_match_tz(PG_FUNCTION_ARGS)
{
return jsonb_path_match_internal(fcinfo, true);
}
/*
* jsonb_path_match_opr
* Implementation of operator "jsonb @@ jsonpath" (2-argument version of
@ -352,7 +384,7 @@ Datum
jsonb_path_match_opr(PG_FUNCTION_ARGS)
{
/* just call the other one -- it can handle both cases */
return jsonb_path_match(fcinfo);
return jsonb_path_match_internal(fcinfo, false);
}
/*
@ -360,8 +392,8 @@ jsonb_path_match_opr(PG_FUNCTION_ARGS)
* Executes jsonpath for given jsonb document and returns result as
* rowset.
*/
Datum
jsonb_path_query(PG_FUNCTION_ARGS)
static Datum
jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
{
FuncCallContext *funcctx;
List *found;
@ -385,7 +417,7 @@ jsonb_path_query(PG_FUNCTION_ARGS)
vars = PG_GETARG_JSONB_P_COPY(2);
silent = PG_GETARG_BOOL(3);
(void) executeJsonPath(jp, vars, jb, !silent, &found);
(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
funcctx->user_fctx = JsonValueListGetList(&found);
@ -406,13 +438,25 @@ jsonb_path_query(PG_FUNCTION_ARGS)
SRF_RETURN_NEXT(funcctx, JsonbPGetDatum(JsonbValueToJsonb(v)));
}
Datum
jsonb_path_query(PG_FUNCTION_ARGS)
{
return jsonb_path_query_internal(fcinfo, false);
}
Datum
jsonb_path_query_tz(PG_FUNCTION_ARGS)
{
return jsonb_path_query_internal(fcinfo, true);
}
/*
* jsonb_path_query_array
* Executes jsonpath for given jsonb document and returns result as
* jsonb array.
*/
Datum
jsonb_path_query_array(PG_FUNCTION_ARGS)
static Datum
jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
{
Jsonb *jb = PG_GETARG_JSONB_P(0);
JsonPath *jp = PG_GETARG_JSONPATH_P(1);
@ -420,18 +464,30 @@ jsonb_path_query_array(PG_FUNCTION_ARGS)
Jsonb *vars = PG_GETARG_JSONB_P(2);
bool silent = PG_GETARG_BOOL(3);
(void) executeJsonPath(jp, vars, jb, !silent, &found);
(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
}
Datum
jsonb_path_query_array(PG_FUNCTION_ARGS)
{
return jsonb_path_query_array_internal(fcinfo, false);
}
Datum
jsonb_path_query_array_tz(PG_FUNCTION_ARGS)
{
return jsonb_path_query_array_internal(fcinfo, true);
}
/*
* jsonb_path_query_first
* Executes jsonpath for given jsonb document and returns first result
* item. If there are no items, NULL returned.
*/
Datum
jsonb_path_query_first(PG_FUNCTION_ARGS)
static Datum
jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
{
Jsonb *jb = PG_GETARG_JSONB_P(0);
JsonPath *jp = PG_GETARG_JSONPATH_P(1);
@ -439,7 +495,7 @@ jsonb_path_query_first(PG_FUNCTION_ARGS)
Jsonb *vars = PG_GETARG_JSONB_P(2);
bool silent = PG_GETARG_BOOL(3);
(void) executeJsonPath(jp, vars, jb, !silent, &found);
(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
if (JsonValueListLength(&found) >= 1)
PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@ -447,6 +503,18 @@ jsonb_path_query_first(PG_FUNCTION_ARGS)
PG_RETURN_NULL();
}
Datum
jsonb_path_query_first(PG_FUNCTION_ARGS)
{
return jsonb_path_query_first_internal(fcinfo, false);
}
Datum
jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
{
return jsonb_path_query_first_internal(fcinfo, true);
}
/********************Execute functions for JsonPath**************************/
/*
@ -470,7 +538,7 @@ jsonb_path_query_first(PG_FUNCTION_ARGS)
*/
static JsonPathExecResult
executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
JsonValueList *result)
JsonValueList *result, bool useTz)
{
JsonPathExecContext cxt;
JsonPathExecResult res;
@ -500,6 +568,7 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
cxt.lastGeneratedObjectId = vars ? 2 : 1;
cxt.innermostArraySize = -1;
cxt.throwErrors = throwErrors;
cxt.useTz = useTz;
if (jspStrictAbsenseOfErrors(&cxt) && !result)
{
@ -1028,6 +1097,12 @@ executeItemOptUnwrapTarget(JsonPathExecContext *cxt, JsonPathItem *jsp,
}
break;
case jpiDatetime:
if (unwrap && JsonbType(jb) == jbvArray)
return executeItemUnwrapTargetArray(cxt, jsp, jb, found, false);
return executeDateTimeMethod(cxt, jsp, jb, found);
case jpiKeyValue:
if (unwrap && JsonbType(jb) == jbvArray)
return executeItemUnwrapTargetArray(cxt, jsp, jb, found, false);
@ -1214,7 +1289,7 @@ executeBoolItem(JsonPathExecContext *cxt, JsonPathItem *jsp,
jspGetLeftArg(jsp, &larg);
jspGetRightArg(jsp, &rarg);
return executePredicate(cxt, jsp, &larg, &rarg, jb, true,
executeComparison, NULL);
executeComparison, cxt);
case jpiStartsWith: /* 'whole STARTS WITH initial' */
jspGetLeftArg(jsp, &larg); /* 'whole' */
@ -1693,6 +1768,136 @@ executeNumericItemMethod(JsonPathExecContext *cxt, JsonPathItem *jsp,
return executeNextItem(cxt, jsp, &next, jb, found, false);
}
/*
* Implementation of the .datetime() method.
*
* Converts a string into a date/time value. The actual type is determined at run time.
* If an argument is provided, this argument is used as a template string.
* Otherwise, the first fitting ISO format is selected.
*/
static JsonPathExecResult
executeDateTimeMethod(JsonPathExecContext *cxt, JsonPathItem *jsp,
JsonbValue *jb, JsonValueList *found)
{
JsonbValue jbvbuf;
Datum value;
text *datetime;
Oid typid;
int32 typmod = -1;
int tz = 0;
bool hasNext;
JsonPathExecResult res = jperNotFound;
JsonPathItem elem;
if (!(jb = getScalar(jb, jbvString)))
RETURN_ERROR(ereport(ERROR,
(errcode(ERRCODE_INVALID_ARGUMENT_FOR_JSON_DATETIME_FUNCTION),
errmsg("jsonpath item method .%s() can only be applied to a string",
jspOperationName(jsp->type)))));
datetime = cstring_to_text_with_len(jb->val.string.val,
jb->val.string.len);
if (jsp->content.arg)
{
text *template;
char *template_str;
int template_len;
bool have_error = false;
jspGetArg(jsp, &elem);
if (elem.type != jpiString)
elog(ERROR, "invalid jsonpath item type for .datetime() argument");
template_str = jspGetString(&elem, &template_len);
template = cstring_to_text_with_len(template_str,
template_len);
value = parse_datetime(datetime, template, true,
&typid, &typmod, &tz,
jspThrowErrors(cxt) ? NULL : &have_error);
if (have_error)
res = jperError;
else
res = jperOk;
}
else
{
/*
* According to SQL/JSON standard enumerate ISO formats for: date,
* timetz, time, timestamptz, timestamp.
*/
static const char *fmt_str[] =
{
"yyyy-mm-dd",
"HH24:MI:SS TZH:TZM",
"HH24:MI:SS TZH",
"HH24:MI:SS",
"yyyy-mm-dd HH24:MI:SS TZH:TZM",
"yyyy-mm-dd HH24:MI:SS TZH",
"yyyy-mm-dd HH24:MI:SS"
};
/* cache for format texts */
static text *fmt_txt[lengthof(fmt_str)] = {0};
int i;
/* loop until datetime format fits */
for (i = 0; i < lengthof(fmt_str); i++)
{
bool have_error = false;
if (!fmt_txt[i])
{
MemoryContext oldcxt =
MemoryContextSwitchTo(TopMemoryContext);
fmt_txt[i] = cstring_to_text(fmt_str[i]);
MemoryContextSwitchTo(oldcxt);
}
value = parse_datetime(datetime, fmt_txt[i], true,
&typid, &typmod, &tz,
&have_error);
if (!have_error)
{
res = jperOk;
break;
}
}
if (res == jperNotFound)
RETURN_ERROR(ereport(ERROR,
(errcode(ERRCODE_INVALID_ARGUMENT_FOR_JSON_DATETIME_FUNCTION),
errmsg("datetime format is not unrecognized"),
errhint("use datetime template argument for explicit format specification"))));
}
pfree(datetime);
if (jperIsError(res))
return res;
hasNext = jspGetNext(jsp, &elem);
if (!hasNext && !found)
return res;
jb = hasNext ? &jbvbuf : palloc(sizeof(*jb));
jb->type = jbvDatetime;
jb->val.datetime.value = value;
jb->val.datetime.typid = typid;
jb->val.datetime.typmod = typmod;
jb->val.datetime.tz = tz;
return executeNextItem(cxt, jsp, &elem, jb, found, hasNext);
}
/*
* Implementation of .keyvalue() method.
*
@ -1953,7 +2158,9 @@ JsonbArraySize(JsonbValue *jb)
static JsonPathBool
executeComparison(JsonPathItem *cmp, JsonbValue *lv, JsonbValue *rv, void *p)
{
return compareItems(cmp->type, lv, rv);
JsonPathExecContext *cxt = (JsonPathExecContext *) p;
return compareItems(cmp->type, lv, rv, cxt->useTz);
}
/*
@ -2048,7 +2255,7 @@ compareStrings(const char *mbstr1, int mblen1,
* Compare two SQL/JSON items using comparison operation 'op'.
*/
static JsonPathBool
compareItems(int32 op, JsonbValue *jb1, JsonbValue *jb2)
compareItems(int32 op, JsonbValue *jb1, JsonbValue *jb2, bool useTz)
{
int cmp;
bool res;
@ -2089,6 +2296,21 @@ compareItems(int32 op, JsonbValue *jb1, JsonbValue *jb2)
cmp = compareStrings(jb1->val.string.val, jb1->val.string.len,
jb2->val.string.val, jb2->val.string.len);
break;
case jbvDatetime:
{
bool have_error = false;
cmp = compareDatetime(jb1->val.datetime.value,
jb1->val.datetime.typid,
jb2->val.datetime.value,
jb2->val.datetime.typid,
useTz,
&have_error);
if (have_error)
return jpbUnknown;
}
break;
case jbvBinary:
case jbvArray:
@ -2348,3 +2570,205 @@ wrapItemsInArray(const JsonValueList *items)
return pushJsonbValue(&ps, WJB_END_ARRAY, NULL);
}
/*
* Cross-type comparison of two datetime SQL/JSON items. If items are
* uncomparable, 'error' flag is set.
*/
static int
compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
bool useTz, bool *have_error)
{
PGFunction cmpfunc = NULL;
switch (typid1)
{
case DATEOID:
switch (typid2)
{
case DATEOID:
cmpfunc = date_cmp;
break;
case TIMESTAMPOID:
val1 = date2timestamp_opt_error(val1, have_error);
if (have_error && *have_error)
return 0;
cmpfunc = timestamp_cmp;
break;
case TIMESTAMPTZOID:
if (!useTz)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert value from %s to %s without timezone usage",
"date", "timestamptz"),
errhint("use *_tz() function for timezone support")));
val1 = date2timestamptz_opt_error(val1, have_error);
if (have_error && *have_error)
return 0;
cmpfunc = timestamp_cmp;
break;
case TIMEOID:
case TIMETZOID:
*have_error = true;
return 0;
}
break;
case TIMEOID:
switch (typid2)
{
case TIMEOID:
cmpfunc = time_cmp;
break;
case TIMETZOID:
if (!useTz)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert value from %s to %s without timezone usage",
"time", "timetz"),
errhint("use *_tz() function for timezone support")));
val1 = DirectFunctionCall1(time_timetz, val1);
cmpfunc = timetz_cmp;
break;
case DATEOID:
case TIMESTAMPOID:
case TIMESTAMPTZOID:
*have_error = true;
return 0;
}
break;
case TIMETZOID:
switch (typid2)
{
case TIMEOID:
if (!useTz)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert value from %s to %s without timezone usage",
"time", "timetz"),
errhint("use *_tz() function for timezone support")));
val2 = DirectFunctionCall1(time_timetz, val2);
cmpfunc = timetz_cmp;
break;
case TIMETZOID:
cmpfunc = timetz_cmp;
break;
case DATEOID:
case TIMESTAMPOID:
case TIMESTAMPTZOID:
*have_error = true;
return 0;
}
break;
case TIMESTAMPOID:
switch (typid2)
{
case DATEOID:
val2 = date2timestamp_opt_error(val2, have_error);
if (have_error && *have_error)
return 0;
cmpfunc = timestamp_cmp;
break;
case TIMESTAMPOID:
cmpfunc = timestamp_cmp;
break;
case TIMESTAMPTZOID:
if (!useTz)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert value from %s to %s without timezone usage",
"timestamp", "timestamptz"),
errhint("use *_tz() function for timezone support")));
val1 = timestamp2timestamptz_opt_error(val1, have_error);
if (have_error && *have_error)
return 0;
cmpfunc = timestamp_cmp;
break;
case TIMEOID:
case TIMETZOID:
*have_error = true;
return 0;
}
break;
case TIMESTAMPTZOID:
switch (typid2)
{
case DATEOID:
if (!useTz)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert value from %s to %s without timezone usage",
"date", "timestamptz"),
errhint("use *_tz() function for timezone support")));
val2 = date2timestamptz_opt_error(val2, have_error);
if (have_error && *have_error)
return 0;
cmpfunc = timestamp_cmp;
break;
case TIMESTAMPOID:
if (!useTz)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot convert value from %s to %s without timezone usage",
"timestamp", "timestamptz"),
errhint("use *_tz() function for timezone support")));
val2 = timestamp2timestamptz_opt_error(val2, have_error);
if (have_error && *have_error)
return 0;
cmpfunc = timestamp_cmp;
break;
case TIMESTAMPTZOID:
cmpfunc = timestamp_cmp;
break;
case TIMEOID:
case TIMETZOID:
*have_error = true;
return 0;
}
break;
default:
elog(ERROR, "unrecognized SQL/JSON datetime type oid: %d",
typid1);
}
if (*have_error)
return 0;
if (!cmpfunc)
elog(ERROR, "unrecognized SQL/JSON datetime type oid: %d",
typid2);
*have_error = false;
return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
}

View File

@ -94,12 +94,14 @@ static JsonPathParseItem *makeItemLikeRegex(JsonPathParseItem *expr,
%token <str> LESS_P LESSEQUAL_P EQUAL_P NOTEQUAL_P GREATEREQUAL_P GREATER_P
%token <str> ANY_P STRICT_P LAX_P LAST_P STARTS_P WITH_P LIKE_REGEX_P FLAG_P
%token <str> ABS_P SIZE_P TYPE_P FLOOR_P DOUBLE_P CEILING_P KEYVALUE_P
%token <str> DATETIME_P
%type <result> result
%type <value> scalar_value path_primary expr array_accessor
any_path accessor_op key predicate delimited_predicate
index_elem starts_with_initial expr_or_predicate
datetime_template opt_datetime_template
%type <elems> accessor_expr
@ -247,9 +249,20 @@ accessor_op:
| array_accessor { $$ = $1; }
| '.' any_path { $$ = $2; }
| '.' method '(' ')' { $$ = makeItemType($2); }
| '.' DATETIME_P '(' opt_datetime_template ')'
{ $$ = makeItemUnary(jpiDatetime, $4); }
| '?' '(' predicate ')' { $$ = makeItemUnary(jpiFilter, $3); }
;
datetime_template:
STRING_P { $$ = makeItemString(&$1); }
;
opt_datetime_template:
datetime_template { $$ = $1; }
| /* EMPTY */ { $$ = NULL; }
;
key:
key_name { $$ = makeItemKey(&$1); }
;
@ -272,6 +285,7 @@ key_name:
| FLOOR_P
| DOUBLE_P
| CEILING_P
| DATETIME_P
| KEYVALUE_P
| LAST_P
| STARTS_P

View File

@ -323,6 +323,7 @@ static const JsonPathKeyword keywords[] = {
{ 6, false, STRICT_P, "strict"},
{ 7, false, CEILING_P, "ceiling"},
{ 7, false, UNKNOWN_P, "unknown"},
{ 8, false, DATETIME_P, "datetime"},
{ 8, false, KEYVALUE_P, "keyvalue"},
{ 10,false, LIKE_REGEX_P, "like_regex"},
};

View File

@ -207,6 +207,7 @@ Section: Class 22 - Data Exception
2200S E ERRCODE_INVALID_XML_COMMENT invalid_xml_comment
2200T E ERRCODE_INVALID_XML_PROCESSING_INSTRUCTION invalid_xml_processing_instruction
22030 E ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE duplicate_json_object_key_value
22031 E ERRCODE_INVALID_ARGUMENT_FOR_JSON_DATETIME_FUNCTION invalid_argument_for_json_datetime_function
22032 E ERRCODE_INVALID_JSON_TEXT invalid_json_text
22033 E ERRCODE_INVALID_SQL_JSON_SUBSCRIPT invalid_sql_json_subscript
22034 E ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM more_than_one_sql_json_item

View File

@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201909214
#define CATALOG_VERSION_NO 201909251
#endif

View File

@ -9332,6 +9332,28 @@
proname => 'jsonb_path_match', prorettype => 'bool',
proargtypes => 'jsonb jsonpath jsonb bool', prosrc => 'jsonb_path_match' },
{ oid => '1177', descr => 'jsonpath exists test with timezone',
proname => 'jsonb_path_exists_tz', provolatile => 's',
prorettype => 'bool', proargtypes => 'jsonb jsonpath jsonb bool',
prosrc => 'jsonb_path_exists_tz' },
{ oid => '1179', descr => 'jsonpath query with timezone',
proname => 'jsonb_path_query_tz', provolatile => 's',
prorows => '1000', proretset => 't',
prorettype => 'jsonb', proargtypes => 'jsonb jsonpath jsonb bool',
prosrc => 'jsonb_path_query_tz' },
{ oid => '1180', descr => 'jsonpath query wrapped into array with timezone',
proname => 'jsonb_path_query_array_tz', provolatile => 's',
prorettype => 'jsonb', proargtypes => 'jsonb jsonpath jsonb bool',
prosrc => 'jsonb_path_query_array_tz' },
{ oid => '2023', descr => 'jsonpath query first item with timezone',
proname => 'jsonb_path_query_first_tz', provolatile => 's',
prorettype => 'jsonb', proargtypes => 'jsonb jsonpath jsonb bool',
prosrc => 'jsonb_path_query_first_tz' },
{ oid => '2030', descr => 'jsonpath match with timezone',
proname => 'jsonb_path_match_tz', provolatile => 's',
prorettype => 'bool', proargtypes => 'jsonb jsonpath jsonb bool',
prosrc => 'jsonb_path_match_tz' },
{ oid => '4010', descr => 'implementation of @? operator',
proname => 'jsonb_path_exists_opr', prorettype => 'bool',
proargtypes => 'jsonb jsonpath', prosrc => 'jsonb_path_exists_opr' },

View File

@ -79,6 +79,7 @@ typedef enum JsonPathItemType
jpiFloor, /* .floor() item method */
jpiCeiling, /* .ceiling() item method */
jpiDouble, /* .double() item method */
jpiDatetime, /* .datetime() item method */
jpiKeyValue, /* .keyvalue() item method */
jpiSubscript, /* array subscript: 'expr' or 'expr TO expr' */
jpiLast, /* LAST array subscript */

View File

@ -1659,6 +1659,526 @@ select jsonb_path_query('[null, 1, "a\b", "a\\b", "^a\\b$"]', 'lax $[*] ? (@ lik
"a\b"
(1 row)
select jsonb_path_query('null', '$.datetime()');
ERROR: jsonpath item method .datetime() can only be applied to a string
select jsonb_path_query('true', '$.datetime()');
ERROR: jsonpath item method .datetime() can only be applied to a string
select jsonb_path_query('1', '$.datetime()');
ERROR: jsonpath item method .datetime() can only be applied to a string
select jsonb_path_query('[]', '$.datetime()');
jsonb_path_query
------------------
(0 rows)
select jsonb_path_query('[]', 'strict $.datetime()');
ERROR: jsonpath item method .datetime() can only be applied to a string
select jsonb_path_query('{}', '$.datetime()');
ERROR: jsonpath item method .datetime() can only be applied to a string
select jsonb_path_query('""', '$.datetime()');
ERROR: datetime format is not unrecognized
HINT: use datetime template argument for explicit format specification
select jsonb_path_query('"12:34"', '$.datetime("aaa")');
ERROR: invalid datetime format separator: "a"
select jsonb_path_query('"aaaa"', '$.datetime("HH24")');
ERROR: invalid value "aa" for "HH24"
DETAIL: Value must be an integer.
select jsonb '"10-03-2017"' @? '$.datetime("dd-mm-yyyy")';
?column?
----------
t
(1 row)
select jsonb_path_query('"10-03-2017"', '$.datetime("dd-mm-yyyy")');
jsonb_path_query
------------------
"2017-03-10"
(1 row)
select jsonb_path_query('"10-03-2017"', '$.datetime("dd-mm-yyyy").type()');
jsonb_path_query
------------------
"date"
(1 row)
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy")');
ERROR: trailing characters remain in input string after datetime format
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy").type()');
ERROR: trailing characters remain in input string after datetime format
select jsonb_path_query('"10-03-2017 12:34"', ' $.datetime("dd-mm-yyyy HH24:MI").type()');
jsonb_path_query
-------------------------------
"timestamp without time zone"
(1 row)
select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM").type()');
jsonb_path_query
----------------------------
"timestamp with time zone"
(1 row)
select jsonb_path_query('"12:34:56"', '$.datetime("HH24:MI:SS").type()');
jsonb_path_query
--------------------------
"time without time zone"
(1 row)
select jsonb_path_query('"12:34:56 +05:20"', '$.datetime("HH24:MI:SS TZH:TZM").type()');
jsonb_path_query
-----------------------
"time with time zone"
(1 row)
set time zone '+00';
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")');
jsonb_path_query
-----------------------
"2017-03-10T12:34:00"
(1 row)
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
ERROR: input string is too short for datetime format
select jsonb_path_query('"10-03-2017 12:34 +05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00+05:00"
(1 row)
select jsonb_path_query('"10-03-2017 12:34 -05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00-05:00"
(1 row)
select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00+05:20"
(1 row)
select jsonb_path_query('"10-03-2017 12:34 -05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00-05:20"
(1 row)
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI")');
jsonb_path_query
------------------
"12:34:00"
(1 row)
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI TZH")');
ERROR: input string is too short for datetime format
select jsonb_path_query('"12:34 +05"', '$.datetime("HH24:MI TZH")');
jsonb_path_query
------------------
"12:34:00+05:00"
(1 row)
select jsonb_path_query('"12:34 -05"', '$.datetime("HH24:MI TZH")');
jsonb_path_query
------------------
"12:34:00-05:00"
(1 row)
select jsonb_path_query('"12:34 +05:20"', '$.datetime("HH24:MI TZH:TZM")');
jsonb_path_query
------------------
"12:34:00+05:20"
(1 row)
select jsonb_path_query('"12:34 -05:20"', '$.datetime("HH24:MI TZH:TZM")');
jsonb_path_query
------------------
"12:34:00-05:20"
(1 row)
set time zone '+10';
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")');
jsonb_path_query
-----------------------
"2017-03-10T12:34:00"
(1 row)
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
ERROR: input string is too short for datetime format
select jsonb_path_query('"10-03-2017 12:34 +05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00+05:00"
(1 row)
select jsonb_path_query('"10-03-2017 12:34 -05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00-05:00"
(1 row)
select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00+05:20"
(1 row)
select jsonb_path_query('"10-03-2017 12:34 -05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:00-05:20"
(1 row)
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI")');
jsonb_path_query
------------------
"12:34:00"
(1 row)
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI TZH")');
ERROR: input string is too short for datetime format
select jsonb_path_query('"12:34 +05"', '$.datetime("HH24:MI TZH")');
jsonb_path_query
------------------
"12:34:00+05:00"
(1 row)
select jsonb_path_query('"12:34 -05"', '$.datetime("HH24:MI TZH")');
jsonb_path_query
------------------
"12:34:00-05:00"
(1 row)
select jsonb_path_query('"12:34 +05:20"', '$.datetime("HH24:MI TZH:TZM")');
jsonb_path_query
------------------
"12:34:00+05:20"
(1 row)
select jsonb_path_query('"12:34 -05:20"', '$.datetime("HH24:MI TZH:TZM")');
jsonb_path_query
------------------
"12:34:00-05:20"
(1 row)
set time zone default;
select jsonb_path_query('"2017-03-10"', '$.datetime().type()');
jsonb_path_query
------------------
"date"
(1 row)
select jsonb_path_query('"2017-03-10"', '$.datetime()');
jsonb_path_query
------------------
"2017-03-10"
(1 row)
select jsonb_path_query('"2017-03-10 12:34:56"', '$.datetime().type()');
jsonb_path_query
-------------------------------
"timestamp without time zone"
(1 row)
select jsonb_path_query('"2017-03-10 12:34:56"', '$.datetime()');
jsonb_path_query
-----------------------
"2017-03-10T12:34:56"
(1 row)
select jsonb_path_query('"2017-03-10 12:34:56 +3"', '$.datetime().type()');
jsonb_path_query
----------------------------
"timestamp with time zone"
(1 row)
select jsonb_path_query('"2017-03-10 12:34:56 +3"', '$.datetime()');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:56+03:00"
(1 row)
select jsonb_path_query('"2017-03-10 12:34:56 +3:10"', '$.datetime().type()');
jsonb_path_query
----------------------------
"timestamp with time zone"
(1 row)
select jsonb_path_query('"2017-03-10 12:34:56 +3:10"', '$.datetime()');
jsonb_path_query
-----------------------------
"2017-03-10T12:34:56+03:10"
(1 row)
select jsonb_path_query('"12:34:56"', '$.datetime().type()');
jsonb_path_query
--------------------------
"time without time zone"
(1 row)
select jsonb_path_query('"12:34:56"', '$.datetime()');
jsonb_path_query
------------------
"12:34:56"
(1 row)
select jsonb_path_query('"12:34:56 +3"', '$.datetime().type()');
jsonb_path_query
-----------------------
"time with time zone"
(1 row)
select jsonb_path_query('"12:34:56 +3"', '$.datetime()');
jsonb_path_query
------------------
"12:34:56+03:00"
(1 row)
select jsonb_path_query('"12:34:56 +3:10"', '$.datetime().type()');
jsonb_path_query
-----------------------
"time with time zone"
(1 row)
select jsonb_path_query('"12:34:56 +3:10"', '$.datetime()');
jsonb_path_query
------------------
"12:34:56+03:10"
(1 row)
set time zone '+00';
-- date comparison
select jsonb_path_query(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ == "10.03.2017".datetime("dd.mm.yyyy"))');
ERROR: cannot convert value from date to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ >= "10.03.2017".datetime("dd.mm.yyyy"))');
ERROR: cannot convert value from date to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ < "10.03.2017".datetime("dd.mm.yyyy"))');
ERROR: cannot convert value from date to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query_tz(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ == "10.03.2017".datetime("dd.mm.yyyy"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10"
"2017-03-10T00:00:00"
"2017-03-10T03:00:00+03:00"
(3 rows)
select jsonb_path_query_tz(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ >= "10.03.2017".datetime("dd.mm.yyyy"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10"
"2017-03-11"
"2017-03-10T00:00:00"
"2017-03-10T12:34:56"
"2017-03-10T03:00:00+03:00"
(5 rows)
select jsonb_path_query_tz(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ < "10.03.2017".datetime("dd.mm.yyyy"))');
jsonb_path_query_tz
-----------------------------
"2017-03-09"
"2017-03-10T01:02:03+04:00"
(2 rows)
-- time comparison
select jsonb_path_query(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ == "12:35".datetime("HH24:MI"))');
ERROR: cannot convert value from time to timetz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ >= "12:35".datetime("HH24:MI"))');
ERROR: cannot convert value from time to timetz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ < "12:35".datetime("HH24:MI"))');
ERROR: cannot convert value from time to timetz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query_tz(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ == "12:35".datetime("HH24:MI"))');
jsonb_path_query_tz
---------------------
"12:35:00"
"12:35:00+00:00"
(2 rows)
select jsonb_path_query_tz(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ >= "12:35".datetime("HH24:MI"))');
jsonb_path_query_tz
---------------------
"12:35:00"
"12:36:00"
"12:35:00+00:00"
(3 rows)
select jsonb_path_query_tz(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ < "12:35".datetime("HH24:MI"))');
jsonb_path_query_tz
---------------------
"12:34:00"
"12:35:00+01:00"
"13:35:00+01:00"
(3 rows)
-- timetz comparison
select jsonb_path_query(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ == "12:35 +1".datetime("HH24:MI TZH"))');
ERROR: cannot convert value from time to timetz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ >= "12:35 +1".datetime("HH24:MI TZH"))');
ERROR: cannot convert value from time to timetz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ < "12:35 +1".datetime("HH24:MI TZH"))');
ERROR: cannot convert value from time to timetz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query_tz(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ == "12:35 +1".datetime("HH24:MI TZH"))');
jsonb_path_query_tz
---------------------
"12:35:00+01:00"
(1 row)
select jsonb_path_query_tz(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ >= "12:35 +1".datetime("HH24:MI TZH"))');
jsonb_path_query_tz
---------------------
"12:35:00+01:00"
"12:36:00+01:00"
"12:35:00-02:00"
"11:35:00"
"12:35:00"
(5 rows)
select jsonb_path_query_tz(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ < "12:35 +1".datetime("HH24:MI TZH"))');
jsonb_path_query_tz
---------------------
"12:34:00+01:00"
"12:35:00+02:00"
"10:35:00"
(3 rows)
-- timestamp comparison
select jsonb_path_query(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
ERROR: cannot convert value from timestamp to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
ERROR: cannot convert value from timestamp to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
ERROR: cannot convert value from timestamp to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query_tz(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10T12:35:00"
"2017-03-10T13:35:00+01:00"
(2 rows)
select jsonb_path_query_tz(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10T12:35:00"
"2017-03-10T12:36:00"
"2017-03-10T13:35:00+01:00"
"2017-03-10T12:35:00-01:00"
"2017-03-11"
(5 rows)
select jsonb_path_query_tz(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10T12:34:00"
"2017-03-10T12:35:00+01:00"
"2017-03-10"
(3 rows)
-- timestamptz comparison
select jsonb_path_query(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
ERROR: cannot convert value from timestamp to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
ERROR: cannot convert value from timestamp to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
ERROR: cannot convert value from timestamp to timestamptz without timezone usage
HINT: use *_tz() function for timezone support
select jsonb_path_query_tz(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10T12:35:00+01:00"
"2017-03-10T11:35:00"
(2 rows)
select jsonb_path_query_tz(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10T12:35:00+01:00"
"2017-03-10T12:36:00+01:00"
"2017-03-10T12:35:00-02:00"
"2017-03-10T11:35:00"
"2017-03-10T12:35:00"
"2017-03-11"
(6 rows)
select jsonb_path_query_tz(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
jsonb_path_query_tz
-----------------------------
"2017-03-10T12:34:00+01:00"
"2017-03-10T12:35:00+02:00"
"2017-03-10T10:35:00"
"2017-03-10"
(4 rows)
set time zone default;
-- jsonpath operators
SELECT jsonb_path_query('[{"a": 1}, {"a": 2}]', '$[*]');
jsonb_path_query

View File

@ -395,6 +395,18 @@ select '$.keyvalue().key'::jsonpath;
$.keyvalue()."key"
(1 row)
select '$.datetime()'::jsonpath;
jsonpath
--------------
$.datetime()
(1 row)
select '$.datetime("datetime template")'::jsonpath;
jsonpath
---------------------------------
$.datetime("datetime template")
(1 row)
select '$ ? (@ starts with "abc")'::jsonpath;
jsonpath
-------------------------

View File

@ -346,6 +346,178 @@ select jsonb_path_query('[null, 1, "a\b", "a\\b", "^a\\b$"]', 'lax $[*] ? (@ lik
select jsonb_path_query('[null, 1, "a\b", "a\\b", "^a\\b$"]', 'lax $[*] ? (@ like_regex "^a\\B$" flag "iq")');
select jsonb_path_query('[null, 1, "a\b", "a\\b", "^a\\b$"]', 'lax $[*] ? (@ like_regex "^a\\b$" flag "")');
select jsonb_path_query('null', '$.datetime()');
select jsonb_path_query('true', '$.datetime()');
select jsonb_path_query('1', '$.datetime()');
select jsonb_path_query('[]', '$.datetime()');
select jsonb_path_query('[]', 'strict $.datetime()');
select jsonb_path_query('{}', '$.datetime()');
select jsonb_path_query('""', '$.datetime()');
select jsonb_path_query('"12:34"', '$.datetime("aaa")');
select jsonb_path_query('"aaaa"', '$.datetime("HH24")');
select jsonb '"10-03-2017"' @? '$.datetime("dd-mm-yyyy")';
select jsonb_path_query('"10-03-2017"', '$.datetime("dd-mm-yyyy")');
select jsonb_path_query('"10-03-2017"', '$.datetime("dd-mm-yyyy").type()');
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy")');
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy").type()');
select jsonb_path_query('"10-03-2017 12:34"', ' $.datetime("dd-mm-yyyy HH24:MI").type()');
select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM").type()');
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()');
set time zone '+00';
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")');
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
select jsonb_path_query('"10-03-2017 12:34 +05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
select jsonb_path_query('"10-03-2017 12:34 -05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
select jsonb_path_query('"10-03-2017 12:34 -05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI")');
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI TZH")');
select jsonb_path_query('"12:34 +05"', '$.datetime("HH24:MI TZH")');
select jsonb_path_query('"12:34 -05"', '$.datetime("HH24:MI TZH")');
select jsonb_path_query('"12:34 +05:20"', '$.datetime("HH24:MI TZH:TZM")');
select jsonb_path_query('"12:34 -05:20"', '$.datetime("HH24:MI TZH:TZM")');
set time zone '+10';
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")');
select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
select jsonb_path_query('"10-03-2017 12:34 +05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
select jsonb_path_query('"10-03-2017 12:34 -05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")');
select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
select jsonb_path_query('"10-03-2017 12:34 -05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")');
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI")');
select jsonb_path_query('"12:34"', '$.datetime("HH24:MI TZH")');
select jsonb_path_query('"12:34 +05"', '$.datetime("HH24:MI TZH")');
select jsonb_path_query('"12:34 -05"', '$.datetime("HH24:MI TZH")');
select jsonb_path_query('"12:34 +05:20"', '$.datetime("HH24:MI TZH:TZM")');
select jsonb_path_query('"12:34 -05:20"', '$.datetime("HH24:MI TZH:TZM")');
set time zone default;
select jsonb_path_query('"2017-03-10"', '$.datetime().type()');
select jsonb_path_query('"2017-03-10"', '$.datetime()');
select jsonb_path_query('"2017-03-10 12:34:56"', '$.datetime().type()');
select jsonb_path_query('"2017-03-10 12:34:56"', '$.datetime()');
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('"12:34:56"', '$.datetime().type()');
select jsonb_path_query('"12:34:56"', '$.datetime()');
select jsonb_path_query('"12:34:56 +3"', '$.datetime().type()');
select jsonb_path_query('"12:34:56 +3"', '$.datetime()');
select jsonb_path_query('"12:34:56 +3:10"', '$.datetime().type()');
select jsonb_path_query('"12:34:56 +3:10"', '$.datetime()');
set time zone '+00';
-- date comparison
select jsonb_path_query(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ == "10.03.2017".datetime("dd.mm.yyyy"))');
select jsonb_path_query(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ >= "10.03.2017".datetime("dd.mm.yyyy"))');
select jsonb_path_query(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ < "10.03.2017".datetime("dd.mm.yyyy"))');
select jsonb_path_query_tz(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ == "10.03.2017".datetime("dd.mm.yyyy"))');
select jsonb_path_query_tz(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ >= "10.03.2017".datetime("dd.mm.yyyy"))');
select jsonb_path_query_tz(
'["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]',
'$[*].datetime() ? (@ < "10.03.2017".datetime("dd.mm.yyyy"))');
-- time comparison
select jsonb_path_query(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ == "12:35".datetime("HH24:MI"))');
select jsonb_path_query(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ >= "12:35".datetime("HH24:MI"))');
select jsonb_path_query(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ < "12:35".datetime("HH24:MI"))');
select jsonb_path_query_tz(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ == "12:35".datetime("HH24:MI"))');
select jsonb_path_query_tz(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ >= "12:35".datetime("HH24:MI"))');
select jsonb_path_query_tz(
'["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]',
'$[*].datetime() ? (@ < "12:35".datetime("HH24:MI"))');
-- timetz comparison
select jsonb_path_query(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ == "12:35 +1".datetime("HH24:MI TZH"))');
select jsonb_path_query(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ >= "12:35 +1".datetime("HH24:MI TZH"))');
select jsonb_path_query(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ < "12:35 +1".datetime("HH24:MI TZH"))');
select jsonb_path_query_tz(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ == "12:35 +1".datetime("HH24:MI TZH"))');
select jsonb_path_query_tz(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ >= "12:35 +1".datetime("HH24:MI TZH"))');
select jsonb_path_query_tz(
'["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]',
'$[*].datetime() ? (@ < "12:35 +1".datetime("HH24:MI TZH"))');
-- timestamp comparison
select jsonb_path_query(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
select jsonb_path_query(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
select jsonb_path_query(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
select jsonb_path_query_tz(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
select jsonb_path_query_tz(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
select jsonb_path_query_tz(
'["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))');
-- timestamptz comparison
select jsonb_path_query(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
select jsonb_path_query(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
select jsonb_path_query(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
select jsonb_path_query_tz(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ == "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
select jsonb_path_query_tz(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ >= "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
select jsonb_path_query_tz(
'["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]',
'$[*].datetime() ? (@ < "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))');
set time zone default;
-- jsonpath operators
SELECT jsonb_path_query('[{"a": 1}, {"a": 2}]', '$[*]');

View File

@ -71,6 +71,8 @@ select '"aaa".type()'::jsonpath;
select 'true.type()'::jsonpath;
select '$.double().floor().ceiling().abs()'::jsonpath;
select '$.keyvalue().key'::jsonpath;
select '$.datetime()'::jsonpath;
select '$.datetime("datetime template")'::jsonpath;
select '$ ? (@ starts with "abc")'::jsonpath;
select '$ ? (@ starts with $var)'::jsonpath;