Skip to content

Commit 1388737

Browse files
author
Liudmila Mantrova
committed
Improved JSON_TABLE description based on Nikita Glukhov's input
1 parent 4578fd5 commit 1388737

File tree

1 file changed

+102
-64
lines changed

1 file changed

+102
-64
lines changed

doc/src/sgml/func-sqljson.sgml

Lines changed: 102 additions & 64 deletions
Original file line numberDiff line numberDiff line change
@@ -902,8 +902,8 @@ INSERT INTO my_films VALUES (
902902
"director" : "Alfred Hitchcock" } ] },
903903
{ "kind" : "thriller", "films" : [
904904
{ "title" : "Vertigo",
905-
"director" : "Hitchcock" } ] },
906-
{ "films" : [
905+
"director" : "Alfred Hitchcock" } ] },
906+
{ "kind" : "drama", "films" : [
907907
{ "title" : "Yojimbo",
908908
"director" : "Akira Kurosawa" } ] }
909909
] }');
@@ -1339,7 +1339,7 @@ SELECT
13391339
FROM my_films;
13401340
json_query
13411341
------------
1342-
["comedy", "horror", "thriller"]
1342+
["comedy", "horror", "thriller", "drama"]
13431343
(1 row)
13441344
</screen>
13451345

@@ -1402,7 +1402,7 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
14021402
<refsynopsisdiv>
14031403
<synopsis>
14041404
JSON_TABLE (
1405-
<replaceable class="parameter">json_api_common_syntax</replaceable> [ AS <replaceable>json_path_name</replaceable> ]
1405+
<replaceable class="parameter">json_api_common_syntax</replaceable> [ AS <replaceable>path_name</replaceable> ]
14061406
COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> [, ...] )
14071407
[ PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
14081408
PLAN DEFAULT ( { INNER | OUTER } [ , { CROSS | UNION } ]
@@ -1412,30 +1412,29 @@ JSON_TABLE (
14121412
<phrase>
14131413
where <replaceable class="parameter">json_table_column</replaceable> is:
14141414
</phrase>
1415-
{ <replaceable>name</replaceable> <replaceable>type</replaceable> [ PATH <replaceable>json_path_specification</replaceable> ]
1416-
[ { ERROR | NULL | DEFAULT expression } ON EMPTY ]
1417-
[ { ERROR | NULL | DEFAULT expression } ON ERROR ]
1418-
| <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
1419-
[ PATH <replaceable>json_path_specification</replaceable> ]
1420-
[ { WITHOUT | WITH { CONDITIONAL | [UNCONDITIONAL] } }
1421-
[ ARRAY ] WRAPPER ]
1422-
[ { KEEP | OMIT } QUOTES [ ON SCALAR STRING ] ]
1423-
[ { ERROR | NULL | EMPTY { ARRAY | OBJECT } } ON EMPTY ]
1424-
[ { ERROR | NULL | EMPTY { ARRAY | OBJECT } } ON ERROR ]
1425-
| NESTED PATH <replaceable>json_path_specification</replaceable> [ AS <replaceable>path_name</replaceable> ]
1426-
COLUMNS ( <replaceable>json_table_column</replaceable> [, ...] )
1427-
| <replaceable>name</replaceable> FOR ORDINALITY }
1415+
<replaceable>name</replaceable> <replaceable>type</replaceable> [ PATH <replaceable>json_path_specification</replaceable> ]
1416+
[ { ERROR | NULL | DEFAULT expression } ON EMPTY ]
1417+
[ { ERROR | NULL | DEFAULT expression } ON ERROR ]
1418+
| <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
1419+
[ PATH <replaceable>json_path_specification</replaceable> ]
1420+
[ { WITHOUT | WITH { CONDITIONAL | [UNCONDITIONAL] } }
1421+
[ ARRAY ] WRAPPER ]
1422+
[ { KEEP | OMIT } QUOTES [ ON SCALAR STRING ] ]
1423+
[ { ERROR | NULL | EMPTY { ARRAY | OBJECT } } ON EMPTY ]
1424+
[ { ERROR | NULL | EMPTY { ARRAY | OBJECT } } ON ERROR ]
1425+
| NESTED PATH <replaceable>json_path_specification</replaceable> [ AS <replaceable>path_name</replaceable> ]
1426+
COLUMNS ( <replaceable>json_table_column</replaceable> [, ...] )
1427+
| <replaceable>name</replaceable> FOR ORDINALITY
14281428
<phrase>
14291429
<replaceable>json_table_plan</replaceable> is:
14301430
</phrase>
1431-
<replaceable>path_name</replaceable> { OUTER | INNER | CROSS | UNION }
1432-
{ <replaceable>path_name</replaceable> | ( <replaceable>nested_plan</replaceable> ) }
1431+
<replaceable>path_name</replaceable> [ { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> ]
1432+
| <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } [...]
1433+
| <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } [...]
14331434
<phrase>
1434-
<replaceable>nested_plan</replaceable> is:
1435+
<replaceable>json_table_plan_primary</replaceable> is:
14351436
</phrase>
1436-
<replaceable>path_name</replaceable> { OUTER | INNER } { <replaceable>path_name</replaceable> | ( <replaceable>nested_plan</replaceable> ) }
1437-
| { <replaceable>path_name</replaceable> | ( <replaceable>nested_plan</replaceable> ) }
1438-
{ { UNION | CROSS } { <replaceable>path_name</replaceable> | ( <replaceable>nested_plan</replaceable> ) } }[...]
1437+
<replaceable>path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
14391438

14401439
</synopsis>
14411440
</refsynopsisdiv>
@@ -1453,9 +1452,9 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
14531452

14541453
<para>
14551454
Taking JSON data as input, <function>JSON_TABLE</function> uses
1456-
a path expression to extract a part of the provided input that
1455+
a path expression to extract a part of the provided data that
14571456
will be used as a <firstterm>row pattern</firstterm> for the
1458-
contructed view. Each SQL/JSON item at the top level of the row pattern serves
1457+
constructed view. Each SQL/JSON item at the top level of the row pattern serves
14591458
as the source for a separate row in the constructed relational view.
14601459
</para>
14611460

@@ -1467,15 +1466,19 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
14671466
the row pattern, extracts a JSON item, and returns it as a
14681467
separate SQL value for the specified column. If the required value
14691468
is stored in a nested level of the row pattern, it can be extracted
1470-
using the <literal>NESTED PATH</literal> subclause.
1469+
using the <literal>NESTED PATH</literal> subclause. Joining the
1470+
columns returned by <literal>NESTED PATH</literal> can add multiple
1471+
new rows to the constructed view. Such rows are called
1472+
<firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
1473+
that generates them.
14711474
</para>
14721475

14731476
<para>
14741477
The rows produced by <function>JSON_TABLE</function> are laterally
14751478
joined to the row that generated them, so you do not have to explicitly join
1476-
the constructed view with the original table. You can specify
1477-
how to handle empty rows returned from the nested levels of
1478-
the row pattern using the <literal>PLAN</literal> clause.
1479+
the constructed view with the original table holding <acronym>JSON</acronym>
1480+
data. Optionally, you can specify how to join the columns returned
1481+
by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
14791482
</para>
14801483

14811484
</refsect1>
@@ -1502,18 +1505,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
15021505

15031506
<varlistentry>
15041507
<term>
1505-
<literal>COLUMNS( { <replaceable class="parameter">json_table_column</replaceable> } [, ...] )</literal>
1508+
<literal>COLUMNS( { <replaceable class="parameter">json_table_column</replaceable> } [, ...] )</literal>
15061509
</term>
15071510
<listitem>
15081511

15091512
<para>
15101513
The <literal>COLUMNS</literal> clause defining the schema of the
1511-
constructed table. In this clause, you must specify all the columns
1512-
to be filled with SQL/JSON items returned by <function>JSON_TABLE</function>.
1513-
You must provide the name and type for each column. Only scalar
1514-
types are supported.
1514+
constructed view. In this clause, you must specify all the columns
1515+
to be filled with SQL/JSON items. Only scalar column types are supported.
15151516
The <replaceable class="parameter">json_table_column</replaceable>
1516-
expression can use one of the following syntax options:
1517+
expression has the following syntax variants:
15171518
</para>
15181519

15191520
<variablelist>
@@ -1601,14 +1602,13 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
16011602
so you can go down multiple nested levels by specifying several
16021603
<literal>NESTED PATH</literal> subclauses within each other.
16031604
It allows to unnest the hierarchy of JSON objects and arrays
1604-
in a single function invocation rather than chaining several <function>JSON_TABLE</function>
1605-
expressions in an SQL statement.
1605+
in a single function invocation rather than chaining several
1606+
<function>JSON_TABLE</function> expressions in an SQL statement.
16061607
</para>
16071608

16081609
<para>
16091610
You can use the <literal>PLAN</literal> clause to define how
1610-
to handle empty rows when joining the columns returned by
1611-
<replaceable>NESTED PATH</replaceable> clauses.
1611+
to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
16121612
</para>
16131613
</listitem>
16141614
</varlistentry>
@@ -1622,7 +1622,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
16221622
<para>
16231623
Adds an ordinality column that provides sequential row numbering.
16241624
You can have only one ordinality column per table. Row numbering
1625-
is 1-based.
1625+
is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
1626+
clauses, the parent row number is repeated.
16261627
</para>
16271628
</listitem>
16281629
</varlistentry>
@@ -1641,28 +1642,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
16411642
The optional <replaceable>json_path_name</replaceable> serves as an
16421643
identifier of the provided <replaceable>json_path_specification</replaceable>.
16431644
The path name must be unique and cannot coincide with column names.
1644-
You must specify the path name when using the <literal>PLAN</literal>
1645-
clause.
1645+
When using the <literal>PLAN</literal> clause, you must specify the names
1646+
for all the paths, including the row pattern. Each path name can appear in
1647+
the <literal>PLAN</literal> clause only once.
16461648
</para>
16471649
</listitem>
16481650
</varlistentry>
16491651

16501652
<varlistentry>
16511653
<term>
1652-
<literal>PLAN <replaceable class="parameter">json_table_plan</replaceable></literal>
1654+
<literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
16531655
</term>
16541656
<listitem>
16551657

16561658
<para>
1657-
Defines how to handle empty rows when joining the columns
1658-
returned by <replaceable>NESTED PATH</replaceable> clauses.
1659+
Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
1660+
clauses to the constructed view.
16591661
</para>
16601662
<para>
1661-
In relation to the columns returned directly from the row expression
1662-
or by the <literal>NESTED PATH</literal> clause of a higher level, nested columns
1663-
are considered to be <firstterm>child</firstterm> columns.
1664-
Each <literal>NESTED PATH</literal> clause can include
1665-
several columns, which are called <firstterm>sibling</firstterm> columns.
1663+
Each <literal>NESTED PATH</literal> clause can generate one or more
1664+
columns, which are considered to be <firstterm>siblings</firstterm>
1665+
to each other. In relation to the columns returned directly from the row
1666+
expression or by the <literal>NESTED PATH</literal> clause of a
1667+
higher level, these columns are <firstterm>child</firstterm> columns.
1668+
Sibling columns are always joined first. Once they are processed,
1669+
the resulting rows are joined to the parent row.
16661670
</para>
16671671
<para>
16681672
To join columns with parent/child relationship, you can use:
@@ -1675,9 +1679,9 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
16751679
<listitem>
16761680

16771681
<para>
1678-
Use <literal>INNER JOIN</literal>, so that the output includes
1679-
only those rows that have the corresponding values in both
1680-
columns.
1682+
Use <literal>INNER JOIN</literal>, so that the parent row
1683+
is omitted from the output if it does not have any child rows
1684+
after joining the data returned by <literal>NESTED PATH</literal>.
16811685
</para>
16821686
</listitem>
16831687
</varlistentry>
@@ -1689,10 +1693,11 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
16891693
<listitem>
16901694

16911695
<para>
1692-
Use <literal>LEFT OUTER JOIN</literal>, so that all rows of the
1693-
left-hand column must be included into the output at least once, while the rows of the right-hand
1694-
column are only included if they have a match in the left column. If the corresponding
1695-
value is missing from the right column, the NULL value is inserted into the right column.
1696+
Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
1697+
is always included into the output even if it does not have any child rows
1698+
after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
1699+
inserted into the child columns if the corresponding
1700+
values are missing.
16961701
</para>
16971702
<para>
16981703
This is the default option for joining columns with parent/child relationship.
@@ -1713,10 +1718,9 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
17131718
<listitem>
17141719

17151720
<para>
1716-
Use <literal>FULL OUTER JOIN</literal>, so that all rows of the
1717-
left-hand and the right-hand columns are included into the output, with
1718-
NULL values inserted into either of the columns if the corresponding value
1719-
is missing.
1721+
Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
1722+
rows are included into the output, with NULL values inserted
1723+
into both child and parrent columns for all missing values.
17201724
</para>
17211725
<para>
17221726
This is the default option for joining sibling columns.
@@ -1745,11 +1749,17 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
17451749

17461750
<varlistentry>
17471751
<term>
1748-
<literal>PLAN DEFAULT</literal>
1752+
<literal>PLAN DEFAULT ( <replaceable>option</replaceable> [, ... ] )</literal>
17491753
</term>
17501754
<listitem>
17511755
<para>
1752-
Redefines the default behavior for all columns at once.
1756+
Overrides the default joining plans. The <literal>INNER</literal> and
1757+
<literal>OUTER</literal> options define the joining plan for parent/child
1758+
columns, while <literal>UNION</literal> and <literal>CROSS</literal>
1759+
affect the sibling columns. You can override the default plans for all columns at once.
1760+
Even though the path names are not incuded into the <literal>PLAN DEFAULT</literal>
1761+
clause, they must be provided for all the paths to conform to
1762+
the SQL/JSON standard.
17531763
</para>
17541764
</listitem>
17551765
</varlistentry>
@@ -1779,8 +1789,36 @@ SELECT jt.* FROM
17791789
1 | comedy | The Dinner Game | Francis Veber
17801790
2 | horror | Psycho | Alfred Hitchcock
17811791
3 | thriller | Vertigo | Hitchcock
1782-
4 | (null) | Yojimbo | Akira Kurosawa
1792+
4 | drama | Yojimbo | Akira Kurosawa
17831793
(5 rows)
1794+
</screen>
1795+
</para>
1796+
1797+
<para>
1798+
Find a director that has done films in two different genres:
1799+
<screen>
1800+
SELECT
1801+
director1 AS director, title1, kind1, title2, kind2
1802+
FROM
1803+
my_films,
1804+
JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
1805+
NESTED PATH '$[*]' AS films1 COLUMNS (
1806+
kind1 text PATH '$.kind',
1807+
NESTED PATH '$.films[*]' AS film1 COLUMNS (
1808+
title1 text PATH '$.title',
1809+
director1 text PATH '$.director')
1810+
),
1811+
NESTED PATH '$[*]' AS films2 COLUMNS (
1812+
kind2 text PATH '$.kind',
1813+
NESTED PATH '$.films[*]' AS film2 COLUMNS (
1814+
title2 text PATH '$.title',
1815+
director2 text PATH '$.director'
1816+
)
1817+
)
1818+
)
1819+
PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
1820+
) AS jt
1821+
WHERE kind1 > kind2 AND director1 = director2;
17841822
</screen>
17851823
</para>
17861824
</refsect1>

0 commit comments

Comments
 (0)