http://qs1969.pair.com?node_id=11134856


in reply to Re: [OT] Re^3: Examples or tutorials for Perl grammars?
in thread Examples or tutorials for Perl grammars?

The SQL Standard, in the part called SQL/JSON, describes syntax, yes. Some DBMSen have it implemented already (for quite some time). PostgreSQL has the functionality but not yet the required syntax.

(In fact the implementation of that syntax for PostgreSQL is waiting to be committed, so I suppose it will be in version 15, next year. It works quite well, and I was able to use the ORACLE and DB2 documentation for SQL/JSON when I was trying it out and looking for examples of that standard-compliant syntax)

PS
There is a link to a SQL/JSON pdf (zipped) in the Bibliography part of the PostgreSQL docs:

PostgreSQL Bibliography

update: fixed typo's!

  • Comment on Re^2: [OT] Re^3: Examples or tutorials for Perl grammars?

Replies are listed 'Best First'.
Re^3: [OT] Re^3: Examples or tutorials for Perl grammars?
by LanX (Saint) on Jul 09, 2021 at 17:49 UTC
    Can I express xpath like queries, like find all elements which are descendants of another element but the direct parent is matching a special criterion?

    How would that look like in SQL?

    Edit

    I'm aware that xpath is for XML and not JSON. Just ignore the missing axes...

    Cheers Rolf
    (addicted to the Perl Programming Language :)
    Wikisyntax for the Monastery

      The SQL-standard's SQL/JSON description uses the term JSON PATH but does not refer to XPath. The postgres docs however say that jsonpath is inspired by XPath.

      "SQL/JSON path expressions specify the items to be retrieved from the JSON data, similar to XPath expressions used for SQL access to XML"

      Here is an example. The JSON table that I use here consists of millions of rows, each row with a so-called JSON document, not very large, and not very deeply nested. It seems to me that this is/will be typical usage. I retrieved test-JSON data from https://extendsclass.com/json-generator.html (h/t choroba).

      One example row with its JSON content:

      { "age": 63, "city": "New York City", "date": "1986-04-03", "array": [ "Lila", "Brandise", "Jsandye" ], "country": "Iceland", "friends": [ { "country": "CA", "lastname": "Yusuk", "firstname": "Deirdre" }, { "country": "AZ", "lastname": "Suanne", "firstname": "Elfreda" }, { "country": "FM", "lastname": "Magdalen", "firstname": "Britte" } ], "lastname": "Hailee", "firstname": "Jaime", "countryCode": "IE", }

      Here is a query example. The @@ is a postgresql operator, but the part in the single quotes is a jsonpath expression which is SQL/JSON-compliant.

      select id, js->'friends' as friends from jsontable where js @@ '$.friends[*].country == "AZ" && $.friends[*].lastname starts with "Y" ' ; id | friends ---------+------------------------------------- 110877 | [ | { | "country": "CA", | "lastname": "Yusuk", | "firstname": "Deirdre" | }, | { | "country": "AZ", | "lastname": "Suanne", | "firstname": "Elfreda" | }, | { | "country": "FM", | "lastname": "Magdalen", | "firstname": "Britte" | } | ] 116322 | [ | { | "country": "AZ", | "lastname": "Ietta", | "firstname": "Wendi" | }, | { | "country": "NG", | "lastname": "Yuille", | "firstname": "Giustina" | }, | { | "country": "MS", | "lastname": "Tengdin", | "firstname": "Adelle" | } | ] 117778 | [ | { | "country": "CK", | "lastname": "Fancie", | "firstname": "Fanny" | }, | { | "country": "JM", | "lastname": "Jerald", | "firstname": "Mureil" | }, | { | "country": "AZ", | "lastname": "Yam", | "firstname": "Wileen" | } | ] [[...]]

      This query returns ~1000 rows (above only 3 are shown) from a 3 GB table with 3 M rows. Thanks to an index on the JSON column (js), the query returns in 120 ms.

      YMMV. It is probably more interesting to try on a real instance. I did some fiddle-ing:

      db-fiddle, postgres 13

      https://www.postgresql.org/docs/current/datatype-json.html#DATATYPE-JSONPATH

        Great!

        «The Crux of the Biscuit is the Apostrophe»