Skip to content

Commit

Permalink
HHH-18758 Add json_table() set-returning function
Browse files Browse the repository at this point in the history
  • Loading branch information
beikov committed Oct 31, 2024
1 parent d6e85b0 commit 8dd5094
Show file tree
Hide file tree
Showing 99 changed files with 6,450 additions and 759 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -1677,18 +1677,19 @@ it is necessary to enable the `hibernate.query.hql.json_functions_enabled` confi
|===
| Function | Purpose
| `json_object()` | Constructs a JSON object from pairs of key and value arguments
| `json_array()` | Constructs a JSON array from arguments
| `json_value()` | Extracts a value from a JSON document by JSON path
| `json_exists()` | Checks if a JSON path exists in a JSON document
| `json_query()` | Queries non-scalar values by JSON path in a JSON document
| `json_arrayagg()` | Creates a JSON array by aggregating values
| `json_objectagg()` | Creates a JSON object by aggregating values
| `json_set()` | Inserts/Replaces a value by JSON path within a JSON document
| `json_remove()` | Removes a value by JSON path within a JSON document
| `json_mergepatch()` | Merges JSON documents by performing an https://tools.ietf.org/html/rfc7396[RFC 7396] compliant merge
| `json_array_append()` | Appends to a JSON array of a JSON document by JSON path
| `json_array_insert()` | Inserts a value by JSON path to a JSON array within a JSON document
| <<hql-json-object-function,`json_object()`>> | Constructs a JSON object from pairs of key and value arguments
| <<hql-json-array-function,`json_array()`>> | Constructs a JSON array from arguments
| <<hql-json-value-function,`json_value()`>> | Extracts a value from a JSON document by JSON path
| <<hql-json-exists-function,`json_exists()`>> | Checks if a JSON path exists in a JSON document
| <<hql-json-query-function,`json_query()`>> | Queries non-scalar values by JSON path in a JSON document
| <<hql-json-arrayagg-function,`json_arrayagg()`>> | Creates a JSON array by aggregating values
| <<hql-json-objectagg-function,`json_objectagg()`>> | Creates a JSON object by aggregating values
| <<hql-json-set-function,`json_set()`>> | Inserts/Replaces a value by JSON path within a JSON document
| <<hql-json-remove-function,`json_remove()`>> | Removes a value by JSON path within a JSON document
| <<hql-json-mergepatch-function,`json_mergepatch()`>> | Merges JSON documents by performing an https://tools.ietf.org/html/rfc7396[RFC 7396] compliant merge
| <<hql-json-array-append-function,`json_array_append()`>> | Appends to a JSON array of a JSON document by JSON path
| <<hql-json-array-insert-function,`json_array_insert()`>> | Inserts a value by JSON path to a JSON array within a JSON document
| <<hql-json-table-function,`json_table()`>> | Turns a JSON document into rows
|===
Expand Down Expand Up @@ -2203,6 +2204,47 @@ include::{json-example-dir-hql}/JsonArrayInsertTest.java[tags=hql-json-array-ins
WARNING: SAP HANA, DB2, H2 and HSQLDB do not support this function.
[[hql-json-table-function]]
===== `json_table()`
A <<hql-from-set-returning-functions,set-returning function>>, which turns a JSON document argument into rows.
Returns no rows if the document is `null` or an empty JSON array.
[[hql-json-table-bnf]]
[source, antlrv4, indent=0]
----
include::{extrasdir}/json_table_bnf.txt[]
----
The first argument is the JSON document. The second optional argument represents the JSON path expression to use
in order to obtain JSON nodes for further processing. The default for the optional second argument is `$[*]`
i.e. access of root array elements.
NOTE: If the root of the JSON document is an object, it is recommended to pass `$` as JSON path for portability.
The `passing` clause can be used to pass values for variables in the JSON path.
Attributes/columns that ought to be accessible via the `from` node alias are defined in the `columns` clause,
which can be of varying forms:
* Value attributes - denoted by a `castTarget` after the name, behaves like <<hql-json-value-function,`json_value()`>>
* Query attributes - denoted by the `json` type after the name, behaves like <<hql-json-query-function,`json_query()`>>
* Exists attributes - denoted by the `exists` keyword after the name, behaves like <<hql-json-exists-function,`json_exists()`>>
* Ordinal attributes - denoted by the `for ordinality` syntax after the name, gives access to the 1-based index of the currently processed array element
* Nested paths - declare a JSON path for processing of a nested `columns` clause
[[hql-json-table-simple-example]]
====
[source, java, indent=0]
----
include::{json-example-dir-hql}/JsonTableTest.java[tags=hql-json-table-example]
----
====
The `lateral` keyword is mandatory if one of the arguments refer to a from node item of the same query level.
WARNING: H2 support is limited and HSQLDB as well as Sybase ASE do not support this function.
[[hql-functions-xml]]
==== Functions for dealing with XML
Expand Down Expand Up @@ -2959,6 +3001,7 @@ The following set-returning functions are available on many platforms:
| <<hql-array-unnest,`unnest()`>> | Turns an array into rows
| <<hql-from-set-returning-functions-generate-series,`generate_series()`>> | Creates a series of values as rows
| <<hql-json-table,`json_table()`>> | Turns a JSON document into rows
|===
To use set returning functions defined in the database, it is required to register them in a `FunctionContributor`:
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
"json_table(" expression ("," expression)? passingClause? columnsClause errorClause? ")"

passingClause
: "passing" expression "as" identifier ("," expression "as" identifier)*

columnsClause
: "columns(" column ("," column)* ")"

column
: "nested" "path"? STRING_LITERAL columnsClause
| attributeName "json" wrapperClause? ("path" STRING_LITERAL)? queryOnErrorClause? queryOnEmptyClause?
| attributeName "for ordinality"
| attributeName "exists" ("path" STRING_LITERAL)? existsOnErrorClause?
| attributeName castTarget ("path" STRING_LITERAL)? valueOnErrorClause? valueOnEmptyClause?

queryOnErrorClause
: ( "error" | "null" | ( "empty" ( "array" | "object" )? ) ) "on error";

queryOnEmptyClause
: ( "error" | "null" | ( "empty" ( "array" | "object" )? ) ) "on empty";

existsOnErrorClause
: ( "error" | "true" | "false" ) "on error"

valueOnErrorClause
: ( "error" | "null" | ( "default" expression ) ) "on error";

valueOnEmptyClause
: ( "error" | "null" | ( "default" expression ) ) "on empty";

errorClause
: ( "error" | "null" ) "on error"
Original file line number Diff line number Diff line change
Expand Up @@ -519,6 +519,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio

functionFactory.unnest_postgresql();
functionFactory.generateSeries( null, "ordinality", true );
functionFactory.jsonTable_cockroachdb();

// Postgres uses # instead of ^ for XOR
functionContributions.getFunctionRegistry().patternDescriptorBuilder( "bitxor", "(?1#?2)" )
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -432,13 +432,14 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.listagg( null );

if ( getDB2Version().isSameOrAfter( 11 ) ) {
functionFactory.jsonValue_no_passing();
functionFactory.jsonValue_db2();
functionFactory.jsonQuery_no_passing();
functionFactory.jsonExists_no_passing();
functionFactory.jsonObject_db2();
functionFactory.jsonArray_db2();
functionFactory.jsonArrayAgg_db2();
functionFactory.jsonObjectAgg_db2();
functionFactory.jsonTable_db2();
}
}

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -429,6 +429,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio

functionFactory.unnest_h2( getMaximumArraySize() );
functionFactory.generateSeries_h2( getMaximumSeriesSize() );
functionFactory.jsonTable_h2( getMaximumArraySize() );
}

/**
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -495,7 +495,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.jsonExists_hana();

functionFactory.unnest_hana();
// functionFactory.json_table();
functionFactory.jsonTable_hana();

functionFactory.generateSeries_hana( getMaximumSeriesSize() );

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -100,6 +100,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
if ( getVersion().isSameOrAfter( 10, 3, 3 ) ) {
if ( getVersion().isSameOrAfter( 10, 6 ) ) {
commonFunctionFactory.unnest_emulated();
commonFunctionFactory.jsonTable_mysql();
}

commonFunctionFactory.inverseDistributionOrderedSetAggregates_windowEmulation();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -674,6 +674,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio

if ( getMySQLVersion().isSameOrAfter( 8 ) ) {
functionFactory.unnest_emulated();
functionFactory.jsonTable_mysql();
}
if ( supportsRecursiveCTE() ) {
functionFactory.generateSeries_recursive( getMaximumSeriesSize(), false, false );
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -312,7 +312,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.jsonValue_oracle();
functionFactory.jsonQuery_oracle();
functionFactory.jsonExists_oracle();
functionFactory.jsonObject_oracle();
functionFactory.jsonObject_oracle( getVersion().isSameOrAfter( 19 ) );
functionFactory.jsonArray_oracle();
functionFactory.jsonArrayAgg_oracle();
functionFactory.jsonObjectAgg_oracle();
Expand All @@ -323,6 +323,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.jsonMergepatch_oracle();
functionFactory.jsonArrayAppend_oracle();
functionFactory.jsonArrayInsert_oracle();
functionFactory.jsonTable_oracle();
}

functionFactory.xmlelement();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -639,6 +639,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.jsonArray();
functionFactory.jsonArrayAgg_postgresql( true );
functionFactory.jsonObjectAgg_postgresql( true );
functionFactory.jsonTable();
}
else {
functionFactory.jsonValue_postgresql();
Expand All @@ -656,6 +657,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.jsonArrayAgg_postgresql( false );
functionFactory.jsonObjectAgg_postgresql( false );
}
functionFactory.jsonTable_postgresql();
}
functionFactory.jsonSet_postgresql();
functionFactory.jsonRemove_postgresql();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -419,6 +419,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.jsonInsert_sqlserver( getVersion().isSameOrAfter( 16 ) );
functionFactory.jsonArrayAppend_sqlserver( getVersion().isSameOrAfter( 16 ) );
functionFactory.jsonArrayInsert_sqlserver();
functionFactory.jsonTable_sqlserver();
}
functionFactory.xmlelement_sqlserver();
functionFactory.xmlcomment_sqlserver();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -161,6 +161,7 @@ CASE : [cC] [aA] [sS] [eE];
CAST : [cC] [aA] [sS] [tT];
COLLATE : [cC] [oO] [lL] [lL] [aA] [tT] [eE];
COLUMN : [cC] [oO] [lL] [uU] [mM] [nN];
COLUMNS : [cC] [oO] [lL] [uU] [mM] [nN] [sS];
CONDITIONAL : [cC] [oO] [nN] [dD] [iI] [tT] [iI] [oO] [nN] [aA] [lL];
CONFLICT : [cC] [oO] [nN] [fF] [lL] [iI] [cC] [tT];
CONSTRAINT : [cC] [oO] [nN] [sS] [tT] [rR] [aA] [iI] [nN] [tT];
Expand Down Expand Up @@ -224,12 +225,14 @@ INTERSECTS : [iI] [nN] [tT] [eE] [rR] [sS] [eE] [cC] [tT] [sS];
INTO : [iI] [nN] [tT] [oO];
IS : [iI] [sS];
JOIN : [jJ] [oO] [iI] [nN];
JSON : [jJ] [sS] [oO] [nN];
JSON_ARRAY : [jJ] [sS] [oO] [nN] '_' [aA] [rR] [rR] [aA] [yY];
JSON_ARRAYAGG : [jJ] [sS] [oO] [nN] '_' [aA] [rR] [rR] [aA] [yY] [aA] [gG] [gG];
JSON_EXISTS : [jJ] [sS] [oO] [nN] '_' [eE] [xX] [iI] [sS] [tT] [sS];
JSON_OBJECT : [jJ] [sS] [oO] [nN] '_' [oO] [bB] [jJ] [eE] [cC] [tT];
JSON_OBJECTAGG : [jJ] [sS] [oO] [nN] '_' [oO] [bB] [jJ] [eE] [cC] [tT] [aA] [gG] [gG];
JSON_QUERY : [jJ] [sS] [oO] [nN] '_' [qQ] [uU] [eE] [rR] [yY];
JSON_TABLE : [jJ] [sS] [oO] [nN] '_' [tT] [aA] [bB] [lL] [eE];
JSON_VALUE : [jJ] [sS] [oO] [nN] '_' [vV] [aA] [lL] [uU] [eE];
KEY : [kK] [eE] [yY];
KEYS : [kK] [eE] [yY] [sS];
Expand Down Expand Up @@ -260,6 +263,7 @@ MINUTE : [mM] [iI] [nN] [uU] [tT] [eE];
MONTH : [mM] [oO] [nN] [tT] [hH];
NAME : [nN] [aA] [mM] [eE];
NANOSECOND : [nN] [aA] [nN] [oO] [sS] [eE] [cC] [oO] [nN] [dD];
NESTED : [nN] [eE] [sS] [tT] [eE] [dD];
NEW : [nN] [eE] [wW];
NEXT : [nN] [eE] [xX] [tT];
NO : [nN] [oO];
Expand All @@ -274,6 +278,7 @@ ON : [oO] [nN];
ONLY : [oO] [nN] [lL] [yY];
OR : [oO] [rR];
ORDER : [oO] [rR] [dD] [eE] [rR];
ORDINALITY : [oO] [rR] [dD] [iI] [nN] [aA] [lL] [iI] [tT] [yY];
OTHERS : [oO] [tT] [hH] [eE] [rR] [sS];
OUTER : [oO] [uU] [tT] [eE] [rR];
OVER : [oO] [vV] [eE] [rR];
Expand All @@ -282,6 +287,7 @@ OVERLAY : [oO] [vV] [eE] [rR] [lL] [aA] [yY];
PAD : [pP] [aA] [dD];
PARTITION : [pP] [aA] [rR] [tT] [iI] [tT] [iI] [oO] [nN];
PASSING : [pP] [aA] [sS] [sS] [iI] [nN] [gG];
PATH : [pP] [aA] [tT] [hH];
PERCENT : [pP] [eE] [rR] [cC] [eE] [nN] [tT];
PLACING : [pP] [lL] [aA] [cC] [iI] [nN] [gG];
POSITION : [pP] [oO] [sS] [iI] [tT] [iI] [oO] [nN];
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -1118,6 +1118,7 @@ function

setReturningFunction
: simpleSetReturningFunction
| jsonTableFunction
;

/**
Expand Down Expand Up @@ -1730,6 +1731,30 @@ jsonUniqueKeysClause
: (WITH|WITHOUT) UNIQUE KEYS
;

jsonTableFunction
: JSON_TABLE LEFT_PAREN expression (COMMA expression)? jsonPassingClause? jsonTableColumnsClause jsonTableErrorClause? RIGHT_PAREN
;

jsonTableErrorClause
: (ERROR|NULL) ON ERROR
;

jsonTableColumnsClause
: COLUMNS LEFT_PAREN jsonTableColumns RIGHT_PAREN
;

jsonTableColumns
: jsonTableColumn (COMMA jsonTableColumn)*
;

jsonTableColumn
: NESTED PATH? STRING_LITERAL jsonTableColumnsClause # JsonTableNestedColumn
| identifier JSON jsonQueryWrapperClause? (PATH STRING_LITERAL)? jsonQueryOnErrorOrEmptyClause? jsonQueryOnErrorOrEmptyClause? # JsonTableQueryColumn
| identifier FOR ORDINALITY # JsonTableOrdinalityColumn
| identifier EXISTS (PATH STRING_LITERAL)? jsonExistsOnErrorClause? # JsonTableExistsColumn
| identifier castTarget (PATH STRING_LITERAL)? jsonValueOnErrorOrEmptyClause? jsonValueOnErrorOrEmptyClause? # JsonTableValueColumn
;

xmlFunction
: xmlelementFunction
| xmlforestFunction
Expand Down Expand Up @@ -1820,6 +1845,7 @@ xmlaggFunction
| CAST
| COLLATE
| COLUMN
| COLUMNS
| CONDITIONAL
| CONFLICT
| CONSTRAINT
Expand Down Expand Up @@ -1885,12 +1911,14 @@ xmlaggFunction
| INTO
| IS
| JOIN
| JSON
| JSON_ARRAY
| JSON_ARRAYAGG
| JSON_EXISTS
| JSON_OBJECT
| JSON_OBJECTAGG
| JSON_QUERY
| JSON_TABLE
| JSON_VALUE
| KEY
| KEYS
Expand Down Expand Up @@ -1921,6 +1949,7 @@ xmlaggFunction
| MONTH
| NAME
| NANOSECOND
| NESTED
| NATURALID
| NEW
| NEXT
Expand All @@ -1936,6 +1965,7 @@ xmlaggFunction
| ONLY
| OR
| ORDER
| ORDINALITY
| OTHERS
// | OUTER
| OVER
Expand All @@ -1944,6 +1974,7 @@ xmlaggFunction
| PAD
| PARTITION
| PASSING
| PATH
| PERCENT
| PLACING
| POSITION
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -488,6 +488,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio

functionFactory.unnest_postgresql();
functionFactory.generateSeries( null, "ordinality", true );
functionFactory.jsonTable_cockroachdb();

// Postgres uses # instead of ^ for XOR
functionContributions.getFunctionRegistry().patternDescriptorBuilder( "bitxor", "(?1#?2)" )
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -418,13 +418,14 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.listagg( null );

if ( getDB2Version().isSameOrAfter( 11 ) ) {
functionFactory.jsonValue_no_passing();
functionFactory.jsonValue_db2();
functionFactory.jsonQuery_no_passing();
functionFactory.jsonExists_no_passing();
functionFactory.jsonObject_db2();
functionFactory.jsonArray_db2();
functionFactory.jsonArrayAgg_db2();
functionFactory.jsonObjectAgg_db2();
functionFactory.jsonTable_db2();
}

functionFactory.xmlelement();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -360,6 +360,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio

functionFactory.unnest_h2( getMaximumArraySize() );
functionFactory.generateSeries_h2( getMaximumSeriesSize() );
functionFactory.jsonTable_h2( getMaximumArraySize() );
}

/**
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -503,7 +503,7 @@ public void initializeFunctionRegistry(FunctionContributions functionContributio
functionFactory.jsonExists_hana();

functionFactory.unnest_hana();
// functionFactory.json_table();
functionFactory.jsonTable_hana();

// Introduced in 2.0 SPS 04
functionFactory.jsonObject_hana();
Expand Down
Loading

0 comments on commit 8dd5094

Please sign in to comment.