Skip to main content

JSON and PL/SQL 12.2: Get values from JSON documents with API


With the release of Oracle Database 12c,  Oracle SQL entered the Age of JSON. You can use SQL to join JSON data with relational data. You can extract content from within the JSON document, and make it available for relational processes and tools. You can even query, right from within the database, JSON data that is stored outside Oracle Database in an external table. Check out my post on JSON resources for more guidance on all of the above.

And that was all possible in 12.1. In Oracle Database 12c Release 2, we added several pre-defined PL/SQL object types to perform fine-grained programmatic construction and manipulation of in-memory JSON data. I'll publish occasional posts on what you can do with these types. Here's the first one, showing you how to get the value for a specific key in a JSON document.

Suppose I've created and populated my species table as follows:

CREATE TABLE json_species
(
   id     NUMBER NOT NULL PRIMARY KEY,
   info   CLOB CONSTRAINT is_json CHECK (info IS JSON ) )
/

BEGIN
   INSERT INTO json_species
        VALUES (1, '{"name":"Spider"}');

   INSERT INTO json_species
        VALUES (2, '{"name":"Elephant", "trunk_length":"10"}');

   INSERT INTO json_species
        VALUES (3, '{"name":"Shark", "fin_count":"4"}');

   COMMIT;
END;
/

If I want to see the values for names in the JSON documents in this table, I can use SQL:

SELECT sp.info.name
  FROM json_species sp


And if this is all you need, there's no reason to bring in the PL/SQL types. If, however, you need to get values in order to perform additional processing on them and perhaps even change the values, the PL/SQL API comes in handy.

So here's how I can get those same values (and display them) in PL/SQL:

DECLARE
   CURSOR species_cur
   IS
      SELECT id, sp.info
        FROM json_species sp
       ORDER BY id;

   l_species   json_object_t;
   l_name      json_element_t;
BEGIN
   FOR rec IN species_cur
   LOOP
      l_species := json_object_t (rec.info);
      l_name := l_species.get ('name');
      DBMS_OUTPUT.put_line (l_name.to_string);
   END LOOP;
END;
/

An explanation of this code:
  • Declare an instance of the JSON_OBJECT_T type.
  • Declare an instance of the JSON_ELEMENT_T type.
  • For every row in the table, get the JSON document (info column) - which, remember is a CLOB, not a JSON document.
  • Create a JSON document from that CLOB by calling the JSON_OBJECT_T constructor function.
  • Call the GET member function of the JSON_OBJECT_T type on the l_species object to get the element for "name". 
  • Call the TO_STRING member function of the JSON_ELEMENT_T type to convert the JSON element into a string.
  • Display that string.
And I see this output:

"Spider"
"Elephant"
"Shark"

[well, I will see all that text, maybe not in that exact order, since I didn't specify an ORDER BY clause in my SELECT. Always good to remember that!]

That was the step-by-step approach, which you will want to use when you are just getting started with these types. If, however, all I wanted to do in PL/SQL was display the value (which I could, remember, do with "pure"  SQL), I could write and execute nothing more than this:

BEGIN
   FOR rec IN (SELECT sp.info FROM json_species sp)
   LOOP
      dbms_output.put_line (
         json_object_t (rec.info).get ('name').to_string);
   END LOOP;
END;
/

Sure, nothing fancy there. And there's lots more to explore. So:

1. If you reading this post before February 8, 2018, be sure to sign up for a CodeTalk session on JSON and PL/SQL I am doing with Darryl Hurley of Implestrat. He knows a lot more about this stuff than me! (for now, anyway :-) )

2. Check out my LiveSQL script with the above code and more.

3. I will be publishing more on this in the weeks to come.

Comments

  1. The link " CodeTalk session on JSON and PL/SQL" is wrong, it has a dot at the end.

    ReplyDelete
  2. Nice article and want to suggest a tool which is developed by me. https://jsonformatter.org for JSON lovers.

    ReplyDelete
  3. Where did Ostrich come from? You only inserted Spider, Elephant and Shark,

    ReplyDelete
    Replies
    1. Excellent question. :-) Ostrich made an appearance in the LiveSQL script but does not belong here. I will remove it. Thanks for the close reading!

      Delete

Post a Comment

Popular posts from this blog

Running out of PGA memory with MULTISET ops? Watch out for DISTINCT!

A PL/SQL team inside Oracle made excellent use of nested tables and MULTISET operators in SQL, blending data in tables with procedurally-generated datasets (nested tables).  All was going well when they hit the dreaded: ORA-04030: out of process memory when trying to allocate 2032 bytes  They asked for my help.  The error occurred on this SELECT: SELECT  *    FROM header_tab trx    WHERE (generated_ntab1 SUBMULTISET OF trx.column_ntab)       AND ((trx.column_ntab MULTISET             EXCEPT DISTINCT generated_ntab2) IS EMPTY) The problem is clearly related to the use of those nested tables. Now, there was clearly sufficient PGA for the nested tables themselves. So the problem was in executing the MULTISET-related functionality. We talked for a bit about dropping the use of nested tables and instead doing everything in SQL, to avoid the PGA error. That would, however require lots of work, revamping algorithms, ensuring correctness, you know the score. Then my eyes snagge

How to Pick the Limit for BULK COLLECT

This question rolled into my In Box today: In the case of using the LIMIT clause of BULK COLLECT, how do we decide what value to use for the limit? First I give the quick answer, then I provide support for that answer Quick Answer Start with 100. That's the default (and only) setting for cursor FOR loop optimizations. It offers a sweet spot of improved performance over row-by-row and not-too-much PGA memory consumption. Test to see if that's fast enough (likely will be for many cases). If not, try higher values until you reach the performance level you need - and you are not consuming too much PGA memory.  Don't hard-code the limit value: make it a parameter to your subprogram or a constant in a package specification. Don't put anything in the collection you don't need. [from Giulio Dottorini] Remember: each session that runs this code will use that amount of memory. Background When you use BULK COLLECT, you retrieve more than row with each fetch,

Quick Guide to User-Defined Types in Oracle PL/SQL

A Twitter follower recently asked for more information on user-defined types in the PL/SQL language, and I figured the best way to answer is to offer up this blog post. PL/SQL is a strongly-typed language . Before you can work with a variable or constant, it must be declared with a type (yes, PL/SQL also supports lots of implicit conversions from one type to another, but still, everything must be declared with a type). PL/SQL offers a wide array of pre-defined data types , both in the language natively (such as VARCHAR2, PLS_INTEGER, BOOLEAN, etc.) and in a variety of supplied packages (e.g., the NUMBER_TABLE collection type in the DBMS_SQL package). Data types in PL/SQL can be scalars, such as strings and numbers, or composite (consisting of one or more scalars), such as record types, collection types and object types. You can't really declare your own "user-defined" scalars, though you can define subtypes  from those scalars, which can be very helpful from the p