Tuesday, December 27, 2016

Storing JSON in Oracle database

Starting with Oracle database 12c (12.1.0.2) Oracle not only introduced Oracle in-memory option but also native JSON support within the Oracle database. Just as with XML in the past, Oracle is now aware of JSON data structures.  This means that you can now persists JSON data in its native structure within the database.  But on top of that you can store and retrieve it in a simple JSON friendly way or access it fully transparently via SQL.

The JSON document store got introduced with XDB component, XDB component was originally introduced in Oracle 9i for handling XML data structures; in 12c XDB component got enhanced to support JSON along with XML data structures, and available within all database editions ( both enterprise edition (EE) and standard edition (SE2) ), this means it is completely free of charge.

Oracle has chosen to store JSON data in existing data types instead of adding new data types.  JSON can be stored in Varchar2, CLOB or BLOB data type, these data types have different properties, Varchar2 can have a maximum length of 32K (when MAX_STRING_SIZE parameter is set to EXTENDED in 12c) or 4000 bytes by default. CLOB encodes characters as UCS2 which means every character takes up two bytes; BLOB doesn’t perform such encoding but instead stores Unicode bytes un-modified.

Let’s start with few rows,

demo@ORA12C> create table t(id int,doc varchar2(4000) );

Table created.

demo@ORA12C> insert into t values (1, '{
  2        "firstName": "Tom",
  3        "lastName": "Kyte",
  4        "location": {
  5          "country": "US",
  6          "city": "Virginia",
  7          "postCode": "VA2M"
  8        }
  9      }' );

1 row created.

demo@ORA12C> insert into t values (2, '{
  2        "firstName": "Dr",
  3        "lastName": "DBA",
  4        "location": {
  5          "country": "US",
  6          "city": "Chicago",
  7          "postCode": "CA"
  8        }
  9      }' );

1 row created.

demo@ORA12C> insert into t values (3, '{
  2        firstName: "Steven",
  3        "lastName": "Flemming",
  4        "location": {
  5          "country": "NZ",
  6          "city": "Nigeria",
  7          "postCode": "NI"
  8        }
  9      }' );

1 row created.

demo@ORA12C> insert into t values (4, 'I am not a valid JSON' );

1 row created.

demo@ORA12C> commit;

Commit complete.

demo@ORA12C>


As one can see the last insert statement inserts data that is not a valid JSON document. So how to identify such a rows? And how to prevent such invalid JSON from being inserted in the first place?

This brings us the new JSON operator IS JSON to find all the valid JSON documents (and invalid JSON documents can be identified using IS NOT JSON


demo@ORA12C> column doc format a20 trunc
demo@ORA12C> select * from t where doc IS JSON;

        ID DOC
---------- --------------------
         1 {
         2 {
         3 {

3 rows selected.

demo@ORA12C> select * from t where doc IS NOT JSON;

        ID DOC
---------- --------------------
         4 I am not a valid JSO

1 row selected.

demo@ORA12C>



If you look carefully at the third row, you’ll see that field name “firstName” is not inside the quotes. Technically this makes the data invalid JSON because the key names need to be enquoted but not everyone follow this rule. The IS JSON operator still accepts this row as JSON, because JSON parser by default runs in tolerant mode.  But not every JSON tool accepts unquoted names (try out http://jsonlint.com/ )


So for JSON sending to others, you may want to validate this and make sure that it compiles to all rules, you can do so by running IS JSON in strict mode.


demo@ORA12C> select * from t
  2  where doc IS JSON STRICT ;

        ID DOC
---------- --------------------
         1 {
         2 {

2 rows selected.

demo@ORA12C>



The JSON specification says nothing about duplicate key names within the same object, for instance this is technically valid JSON although it has two keys with the same FIRSTNAME.

{
      "firstName": "Steven",
      "lastName": "Flemming",
      "location": {
        "country": "NZ",
        "city": "Nigeria",
        "postCode": "NI"
      } ,
      "firstName": "Tom"
}


How to avoid those duplicate key names? The clause WITH UNIQUE KEYS checks that keys are not repeated within the same object level (keys with the same name can occur at multiple places in the data but not in the same object).


demo@ORA12C>
demo@ORA12C> insert into t values( 5,
  2  ' {
  3        "firstName": "Steven",
  4        "lastName": "Flemming",
  5        "location": {
  6          "country": "NZ",
  7          "city": "Nigeria",
  8          "postCode": "NI"
  9        } ,
 10       "firstName": "Tom"
 11  } ') ;

1 row created.

demo@ORA12C>
demo@ORA12C> commit;

Commit complete.

demo@ORA12C> select * from t
  2  where doc IS JSON STRICT ;

        ID DOC
---------- --------------------
         5 {
         1 {
         2 {

3 rows selected.

demo@ORA12C> select * from t
  2  where doc IS JSON STRICT WITH UNIQUE KEYS ;

        ID DOC
---------- --------------------
         1 {
         2 {

2 rows selected.

demo@ORA12C>


So now we understand the IS JSON, how can we use that to prevent non-JSON data to be inserted into our table in the first place?   The answer would be to use a check constraint. 

demo@ORA12C> truncate table t;

Table truncated.

demo@ORA12C>
demo@ORA12C> alter table t
  2  add constraint check_json_valid
  3  check( doc IS JSON STRICT );

Table altered.

demo@ORA12C> column column_name format a10
demo@ORA12C> select column_name,data_type
  2  from user_json_columns
  3  where table_name ='T';

COLUMN_NAM DATA_TYPE
---------- -------------
DOC        VARCHAR2

1 row selected.

demo@ORA12C> insert into t values(1, '{
  2        "firstName": "Tom",
  3        "lastName": "Kyte",
  4        "location": {
  5          "country": "US",
  6          "city": "Virginia",
  7          "postCode": "VA2M"
  8        }
  9      }' );

1 row created.

demo@ORA12C> insert into t values(2, '{
  2        "firstName": "Dr",
  3        "lastName": "DBA",
  4        "location": {
  5          "country": "US",
  6          "city": "Chicago",
  7          "postCode": "CA"
  8        }
  9      }' );

1 row created.

demo@ORA12C> insert into t values(3, '{
  2        firstName: "Steven",
  3        "lastName": "Flemming",
  4        "location": {
  5          "country": "NZ",
  6          "city": "Nigeria",
  7          "postCode": "NI"
  8        }
  9      }' );
insert into t values(3, '{
*
ERROR at line 1:
ORA-02290: check constraint (DEMO.CHECK_JSON_VALID) violated


Check constraint violated due to the missing quotes around the key “first_name”. (Since the check constraint is IS JSON STRICT)


demo@ORA12C> insert into t values(4, 'I am not a valid JSON' );
insert into t values(4, 'I am not a valid JSON' )
*
ERROR at line 1:
ORA-02290: check constraint (DEMO.CHECK_JSON_VALID) violated


Check constraint violated due invalid JSON format.


demo@ORA12C> insert into t values( 5,
  2  ' {
  3        "firstName": "Steven",
  4        "lastName": "Flemming",
  5        "location": {
  6          "country": "NZ",
  7          "city": "Nigeria",
  8          "postCode": "NI"
  9        } ,
 10       "firstName": "Tom"
 11  } ') ;

1 row created.

demo@ORA12C>

No, Check constraint violation, because check constraint is defined with IS JSON STRICT option – so no options to check for duplicate keys with in the object. Hence it got bypassed and loaded into the table.

Thursday, December 22, 2016

Getting started with Oracle database In-memory

The objects with INMEMORY attribute are populated into IM column store. This INMEMORY attribute can be specified on a Tablespace, Table, (sub) partition or materialized views, for a partitioned table, all the partitions inherit the INMEMORY attribute but it is possible to populate just a subset of partitions or sub-partitions. 

You can identify which tables have the INMEMORY attribute, by looking at the new INMEMORY column from user_tables dictionary tables. 

demo@ORA12C> select table_name, inmemory
  2  from user_tables;

TABLE_NAME      INMEMORY
--------------- --------
BIG_TABLE       ENABLED
SALES

2 rows selected.

In the example above, you will notice that table SALES don’t have a value for this “INMEMORY” column. Since the table SALES is partitioned, the INMEMORY attribute will be recorded at user_tab_partitions dictionary tables.

demo@ORA12C> select table_name,partition_name, inmemory
  2  from user_tab_partitions;

TABLE_NAME      PARTITION_NAME  INMEMORY
--------------- --------------- --------
SALES           P1              ENABLED
SALES           P2              ENABLED

2 rows selected.


The IM column store is populated by a set of background processes referred to as worker processes (ora_w001_xxxx). Each worker process is given a subset of database blocks from the object to populate into the IM column store. Population is a streaming mechanism, simultaneously columnizing and compressing the data.


demo@ORA12C> select program,pname,
  2      regexp_replace( tracefile ,
  3        '\S+\\(\S+)\.\S+','\1') process_name
  4  from v$process where pname like 'W%';

PROGRAM              PNAME PROCESS_NAME
-------------------- ----- ---------------------
ORACLE.EXE (W000)    W000  ora12c_w000_3780
ORACLE.EXE (W001)    W001  ora12c_w001_3860
ORACLE.EXE (W002)    W002  ora12c_w002_1872
ORACLE.EXE (W003)    W003  ora12c_w003_3200
ORACLE.EXE (W005)    W005  ora12c_w005_3352
ORACLE.EXE (W004)    W004  ora12c_w004_3696

6 rows selected.

demo@ORA12C>


The compression used during the population of the IM column store is different to any of Oracle’s previous types of compression. These new compression algorithms not only help save space but also improve query performance by allowing queries to execute directly against the compressed columns. This means all scanning and filtering operations will execute on a much smaller amount of data. Data is only decompressed when it is required for the result set.

Inmemory compression is specified using the keyword MEMCOMPRESS, a sub-clause of INMEMORY attribute, there are six levels each of which provides different level of compression and performance.

demo@ORA12C> create table sales
  2  partition by hash(object_id)
  3  ( partition p1 inmemory no memcompress ,
  4    partition p2 inmemory memcompress for dml,
  5    partition p3 inmemory memcompress for query low,
  6    partition p4 inmemory memcompress for query high,
  7    partition p5 inmemory memcompress for capacity low,
  8    partition p6 inmemory memcompress for capacity high )
  9  as
 10  select * from big_table;

Table created.

demo@ORA12C> select table_name, partition_name,
  2         inmemory, inmemory_compression
  3  from user_tab_partitions;

TABLE_NAME      PARTITION_NAME  INMEMORY INMEMORY_COMPRESS
--------------- --------------- -------- -----------------
SALES           P1              ENABLED  NO MEMCOMPRESS
SALES           P2              ENABLED  FOR DML
SALES           P3              ENABLED  FOR QUERY LOW
SALES           P4              ENABLED  FOR QUERY HIGH
SALES           P5              ENABLED  FOR CAPACITY LOW
SALES           P6              ENABLED  FOR CAPACITY HIGH

6 rows selected.

demo@ORA12C>


Objects are populated into the IM column store either in a prioritized list immediately after the database is opened or after they are scanned (queried) for the first time. The order in which objects are populated is controlled by the keyword PRIORITY, a sub-clause of the INMEMORY attribute. There are five levels from CRITICAL ,HIGH, MEDIUM, LOW to NONE.

The default PRIORITY is NONE, which means an object is populated only after it is scanned for the first time. All objects at a given priority level must be fully populated before the population for any objects at a lower priority level can commence

You can identify the PRIORITY levels that have been specified on the table or partitions by looking at user_tables or user_tab_partitions.


demo@ORA12C> alter table sales modify partition p5 inmemory priority critical;

Table altered.

demo@ORA12C> select table_name,partition_name,
  2         inmemory , inmemory_priority
  3  from user_tab_partitions;

TABLE_NAME      PARTITION_NAME  INMEMORY INMEMORY
--------------- --------------- -------- --------
SALES           P1              ENABLED  NONE
SALES           P2              ENABLED  NONE
SALES           P3              ENABLED  NONE
SALES           P4              ENABLED  NONE
SALES           P5              ENABLED  CRITICAL
SALES           P6              ENABLED  NONE

6 rows selected.

demo@ORA12C>


V$IM_SEGMENTS can be used to monitor the contents of these IM column store. These views show which objects are currently populated, or being populated, into the IM column store (POPULATE_STATUS), as well as indicating whether the entire object has been populated (BYTES_NOT_POPULATED).

demo@ORA12C> select segment_name,
  2    partition_name,
  3    inmemory_size,bytes,
  4    bytes_not_populated,
  5    populate_status,
  6    round(bytes/inmemory_size,2) compress_factor
  7  from v$im_segments ;

SEGMENT_NA PAR INMEMORY_SIZE      BYTES BYTES_NOT_POPULATED POPULATE_ COMPRESS_FACTOR
---------- --- ------------- ---------- ------------------- --------- ---------------
SALES      P4        4325376   33554432                   0 COMPLETED            7.76
SALES      P1       13762560   16777216                   0 COMPLETED            1.22
SALES      P6        2228224   16777216                   0 COMPLETED            7.53
SALES      P3        7471104   33554432                   0 COMPLETED            4.49
BIG_TABLE            7536640  131137536                   0 COMPLETED            17.4
SALES      P5        4325376   16777216                   0 COMPLETED            3.88
SALES      P2       13762560   16777216                   0 COMPLETED            1.22

7 rows selected.

demo@ORA12C>

Enabling Oracle database in-memory

Oracle database in-memory is not a bolt on technology to the Oracle database, It has been seamlessly integrated into the core of database as a new component of the shared global area (SGA).  Oracle database in-memory is as a new feature in 12c (12.1.0.2) and above. When Oracle database is installed, Oracle database in-memory is installed and not enabled by default.

demo@ORA12C> show parameter inmemory

NAME                                          TYPE        VALUE
--------------------------------------------- ----------- ---------
inmemory_clause_default                       string
inmemory_force                                string      DEFAULT
inmemory_max_populate_servers                 integer     0
inmemory_query                                string      ENABLE
inmemory_size                                 big integer 0
inmemory_trickle_repopulate_servers_percent   integer     1
optimizer_inmemory_aware                      boolean     TRUE


Database in-memory uses an in-memory column store (IM Column store), which is a new component of the SGA, called In-memory Area. Data in the in-memory column store does not reside in the traditional row format used by buffer cache, but instead in a new column format.  The size of the in-memory column store is controlled by INMEMORY_SIZE parameter, as you can see inmemory_size is set to zero and therefore Database in-memory is not enabled and there is no IM column store allocation. We can also confirm that in-memory area is not allocated by querying V$SGA. 

demo@ORA12C> select name,value from v$sga;

NAME                                VALUE
------------------------------ ----------
Fixed Size                        3055944
Variable Size                   922750648
Database Buffers               4076863488
Redo Buffers                     13717504

4 rows selected.


We can also confirm that in-memory is not enabled by querying feature tracking information.

demo@ORA12C> column name format a30
demo@ORA12C> select name,version,detected_usages,
  2         total_samples,currently_used,first_usage_date
  3  from dba_feature_usage_statistics
  4  where name like 'In-%';

NAME                    VERSION    DETECTED_USAGES TOTAL_SAMPLES CURRE FIRST_USAGE
----------------------- ---------- --------------- ------------- ----- -----------
In-Memory Aggregation   12.1.0.2.0               0             1 FALSE
In-Memory Column Store  12.1.0.2.0               0             1 FALSE

2 rows selected.


Enabling database in-memory is actually a multi-step process.

Step 1: first we must allocate the memory for the IM column store by setting up INMEMORY_SIZE parameter to a non-zero value.

Since IM column store is part of the SGA, we also need to ensure that SGA_TARGET parameter is set to large enough to accommodate the new IM column store along with the other components (buffer cache, shared pool, large pool etc).


demo@ORA12C> show parameter memory_max

NAME                                          TYPE        VALUE
--------------------------------------------- ----------- -------------------------
inmemory_max_populate_servers                 integer     0
memory_max_target                             big integer 0
demo@ORA12C> show parameter memory_target

NAME                                          TYPE        VALUE
--------------------------------------------- ----------- -------------------------
memory_target                                 big integer 0
demo@ORA12C> show parameter sga

NAME                                          TYPE        VALUE
--------------------------------------------- ----------- -------------------------
lock_sga                                      boolean     FALSE
pre_page_sga                                  boolean     TRUE
sga_max_size                                  big integer 4784M
sga_target                                    big integer 4784M
unified_audit_sga_queue_size                  integer     1048576
demo@ORA12C>
demo@ORA12C>
demo@ORA12C> alter system set sga_max_size = 6G scope=spfile;

System altered.

demo@ORA12C> alter system set sga_target = 6G scope=spfile;

System altered.

demo@ORA12C> alter system set inmemory_size=1G scope=spfile;

System altered.

demo@ORA12C>


Next, let’s bounce the database so that these parameter changes can take effect.


demo@ORA12C> conn sys/Password-1@ora12c as sysdba
Connected.
sys@ORA12C> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
ERROR:
ORA-12514: TNS:listener does not currently know of service requested in connect descripto


Warning: You are no longer connected to ORACLE.
sys@ORA12C>
sys@ORA12C> exit

C:\Users\Administrator>set ORACLE_SID=ORA12C

C:\Users\Administrator>sqlplus sys/Password-1 as sysdba

SQL*Plus: Release 12.1.0.2.0 Production on Mon Dec 19 23:09:24 2016

Copyright (c) 1982, 2014, Oracle.  All rights reserved.

Connected to an idle instance.

idle> startup
ORACLE instance started.

Total System Global Area 6442450944 bytes
Fixed Size                  3060040 bytes
Variable Size            1040191160 bytes
Database Buffers         4311744512 bytes
Redo Buffers               13713408 bytes
In-Memory Area           1073741824 bytes
Database mounted.
Database opened.
idle>
idle> conn demo/demo@ora12c
Connected.
demo@ORA12C>
demo@ORA12C> show parameter sga_target

NAME                                          TYPE        VALUE
--------------------------------------------- ----------- ------
sga_target                                    big integer 6G
demo@ORA12C> show parameter inmemory_size

NAME                                          TYPE        VALUE
--------------------------------------------- ----------- ------
inmemory_size                                 big integer 1G
demo@ORA12C>
demo@ORA12C> select name,value from v$sga;

NAME                    VALUE
------------------ ----------
Fixed Size            3060040
Variable Size       922750648
Database Buffers   4429185024
Redo Buffers         13713408
In-Memory Area     1073741824
                  
5 rows selected.

demo@ORA12C>


As you can see, we now have an IM Column store, but database in-memory is still not in use, because no objects have been populated into the IM Column store. To confirm this we can look at the view v$im_segments.


demo@ORA12C> select owner,segment_name,inmemory_size,bytes,
  2         bytes_not_populated,populate_status
  3  from v$im_segments ;

no rows selected


Only the object with INMEMORY attribute are populated into IM column store, the INMEMORY attribute can be specified on a Tablespace, Table, (sub) partition or materialized views.  In this case let’s enable INMEMORY attribute on one of the user table BIG_TABLE.

demo@ORA12C> alter table big_table inmemory;

Table altered.


By default Oracle automatically decides when to populate this table into IM column store, as oracle typically populates the table after it has been accessed for the first time. So let’s run the query on the BIG_TABLE.

demo@ORA12C> select owner,segment_name,inmemory_size,bytes,
  2         bytes_not_populated,populate_status
  3  from v$im_segments ;

no rows selected

demo@ORA12C> select count(*) from big_table;

  COUNT(*)
----------
   1000000

1 row selected.

demo@ORA12C> select owner,segment_name,inmemory_size,bytes,
  2         bytes_not_populated,populate_status
  3  from v$im_segments ;

OWNER      SEGMENT_NA INMEMORY_SIZE      BYTES BYTES_NOT_POPULATED POPULATE_
---------- ---------- ------------- ---------- ------------------- ---------
DEMO       BIG_TABLE       27459584  131137536                   0 COMPLETED

1 row selected.


If we check the feature tracking information now, we will see Database in-memory is enabled and being used.

demo@ORA12C> exec sys.DBMS_FEATURE_USAGE_INTERNAL.exec_db_usage_sampling(sysdate);
BEGIN sys.DBMS_FEATURE_USAGE_INTERNAL.exec_db_usage_sampling(sysdate); END;

      *
ERROR at line 1:
ORA-06550: line 1, column 7:
PLS-00201: identifier 'SYS.DBMS_FEATURE_USAGE_INTERNAL' must be declared
ORA-06550: line 1, column 7:
PL/SQL: Statement ignored


demo@ORA12C> conn sys/Password-@ora12c as sysdba
Connected.
sys@ORA12C> grant execute on DBMS_FEATURE_USAGE_INTERNAL to demo;

Grant succeeded.

sys@ORA12C> conn demo/demo@ora12c
Connected.
demo@ORA12C> exec sys.DBMS_FEATURE_USAGE_INTERNAL.exec_db_usage_sampling(sysdate);

PL/SQL procedure successfully completed.

demo@ORA12C> column name format a30
demo@ORA12C> select name,version,detected_usages,
  2         total_samples,currently_used,first_usage_date
  3  from dba_feature_usage_statistics
  4  where name like 'In-%';

NAME                   VERSION    DETECTED_USAGES TOTAL_SAMPLES CURRE FIRST_USAGE
---------------------- ---------- --------------- ------------- ----- -----------
In-Memory Aggregation  12.1.0.2.0               0             1 FALSE
In-Memory Column Store 12.1.0.2.0               1             1 FALSE 19-DEC-2016

2 rows selected.


If you want to remove the table from the IM column store, you simply need to specify the NO INMEMORY attribute.


demo@ORA12C> alter table big_table no inmemory;

Table altered.

demo@ORA12C> select owner,segment_name,inmemory_size,bytes,
  2         bytes_not_populated,populate_status
  3  from v$im_segments;

no rows selected

You could also enable IM column store for a subset of columns in table using NO INMEMORY option on a set of excluded column list.

demo@ORA12C> set linesize 71
demo@ORA12C> desc big_table
 Name                 Null?    Type
 -------------------- -------- -------------
 OWNER                NOT NULL VARCHAR2(128)
 OBJECT_NAME          NOT NULL VARCHAR2(128)
 SUBOBJECT_NAME                VARCHAR2(128)
 OBJECT_ID            NOT NULL NUMBER
 DATA_OBJECT_ID                NUMBER
 OBJECT_TYPE                   VARCHAR2(23)
 CREATED              NOT NULL DATE
 LAST_DDL_TIME        NOT NULL DATE
 TIMESTAMP                     VARCHAR2(19)
 STATUS                        VARCHAR2(7)
 TEMPORARY                     VARCHAR2(1)
 GENERATED                     VARCHAR2(1)
 SECONDARY                     VARCHAR2(1)
 NAMESPACE            NOT NULL NUMBER
 EDITION_NAME                  VARCHAR2(128)
 SHARING                       VARCHAR2(13)
 EDITIONABLE                   VARCHAR2(1)
 ORACLE_MAINTAINED             VARCHAR2(1)
 ID                            NUMBER

demo@ORA12C>
demo@ORA12C> alter table big_table inmemory no inmemory(
  2  OBJECT_NAME ,SUBOBJECT_NAME ,
  3  DATA_OBJECT_ID ,OBJECT_TYPE ,CREATED ,
  4  LAST_DDL_TIME, TIMESTAMP, STATUS,
  5  TEMPORARY, GENERATED, SECONDARY,
  6  NAMESPACE, EDITION_NAME, SHARING,
  7  EDITIONABLE, ORACLE_MAINTAINED, ID );

Table altered.

demo@ORA12C> select count(*) from big_table;

  COUNT(*)
----------
   1000000

1 row selected.

demo@ORA12C> select owner,segment_name,inmemory_size,bytes,
  2         bytes_not_populated,populate_status
  3  from v$im_segments ;

OWNER      SEGMENT_NA INMEMORY_SIZE      BYTES BYTES_NOT_POPULATED POPULATE_
---------- ---------- ------------- ---------- ------------------- ---------
DEMO       BIG_TABLE        7536640  131137536                   0 COMPLETED

1 row selected.

demo@ORA12C>

Monday, December 19, 2016

Transforming Relational data to JSON format


As of 12cR1 (121.0.2) oracle doesn’t have any native API for converting relation data to JSON format.

But with SQLCL in place, that got easy with SQLFORMAT command or annotated JSON hint.

C:\Users\179818>sql /nolog

SQLcl: Release 4.2.0 Production on Wed Dec 14 16:55:56 2016

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


        New version: 4.2.0.1 available to download


idle> conn demo/demo@ora12c
Connected.


demo@ORA12C> select * from dept;

    DEPTNO DNAME          LOC
---------- -------------- -------------
        10 ACCOUNTING     NEW YORK
        20 RESEARCH       DALLAS
        30 SALES          CHICAGO
        40 OPERATIONS     BOSTON

4 rows selected.


demo@ORA12C> help set sqlformat
SET SQLFORMAT
  SET SQLFORMAT { csv,html,xml,json,ansiconsole,insert,loader,fixed,default}


demo@ORA12C> set sqlformat json

demo@ORA12C> select * from dept;
{"results":[{"columns":[{"name":"DEPTNO","type":"NUMBER"},{"name":"DNAME","type":"NUMBER"},{"name":"LOC","type":"NUMBER"}],"items":
[
{"deptno":10,"dname":"ACCOUNTING","loc":"NEW YORK"},{"deptno":20,"dname":"RESEARCH","loc":"DALLAS"},{"deptno":30,"dname":"SALES","loc":"CHICAGO"},{"deptno":40,"dname":"OPERATIONS","lo
c":"BOSTON"}]}]}
4 rows selected.


demo@ORA12C> set sqlformat
SQL Format Cleared

demo@ORA12C> select * from dept;

    DEPTNO DNAME          LOC
---------- -------------- -------------
        10 ACCOUNTING     NEW YORK
        20 RESEARCH       DALLAS
        30 SALES          CHICAGO
        40 OPERATIONS     BOSTON

4 rows selected.


demo@ORA12C> select /*json*/ * from dept;
{"results":[{"columns":[{"name":"DEPTNO","type":"NUMBER"},{"name":"DNAME","type":"NUMBER"},{"name":"LOC","type":"NUMBER"}],"items":
[
{"deptno":10,"dname":"ACCOUNTING","loc":"NEW YORK"},{"deptno":20,"dname":"RESEARCH","loc":"DALLAS"},{"deptno":30,"dname":"SALES","loc":"CHICAGO"},{"deptno":40,"dname":"OPERATIONS","lo
c":"BOSTON"}]}]}
4 rows selected.


demo@ORA12C>

However this option SET SQLFORMAT or JSON annotated hint is not available on sql*plus or JDBC/ODBC drivers, and we don’t have native API for converting relation data to JSON format yet.

How to server the application that requires JSON as output from the database? The workaround would be to convert the relation data to XML and then convert it to JSON using style sheet transformation.

demo@ORA12C> CREATE OR REPLACE FUNCTION refcursor_to_json(x VARCHAR2)
  2  RETURN CLOB AS
  3        lhtmloutput   xmltype;
  4        lxsl          LONG;
  5        lxmldata      xmltype;
  6        lcontext      dbms_xmlgen.ctxhandle;
  7        l_ret_clob    CLOB;
  8        desc_cur      NUMBER;
  9        l_descr_tab   dbms_sql.desc_tab2;
 10        l_num_cols    NUMBER;
 11        l_header_clob CLOB;
 12        l_row_data    VARCHAR2(100);
 13        l_ip_rfc      SYS_REFCURSOR;
 14        l_exec_comm   VARCHAR2(250);
 15        n number ;
 16  BEGIN
 17        l_exec_comm := 'SELECT ' ||
 18                             dbms_assert.simple_sql_name(x)
 19                       || ' from dual';
 20
 21        EXECUTE IMMEDIATE l_exec_comm
 22                        INTO l_ip_rfc;
 23
 24        l_header_clob := '{"metadata":[';
 25        desc_cur      := dbms_sql.to_cursor_number(l_ip_rfc);
 26
 27        dbms_sql.describe_columns2(desc_cur
 28                             ,l_num_cols
 29                             ,l_descr_tab);
 30
 31        FOR i IN 1 .. l_num_cols
 32        LOOP
 33                        CASE
 34                             WHEN l_descr_tab(i).col_type IN (2,8) THEN
 35                             l_row_data := '{"name":"' || l_descr_tab(i)
 36                                     .col_name || '","type":"number"},';
 37                             WHEN l_descr_tab(i).col_type = 12 THEN
 38                                     l_row_data := '{"name":"' || l_descr_tab(i)
 39                                         .col_name || '","type":"date"},';
 40                             ELSE
 41                                  l_row_data := '{"name":"' || l_descr_tab(i)
 42                                   .col_name || '","type":"text"},';
 43                        END CASE;
 44                        dbms_lob.writeappend(l_header_clob
 45                                     ,length(l_row_data)
 46                                     ,l_row_data);
 47        END LOOP;
 48        l_header_clob := rtrim(l_header_clob
 49                                ,',') || '],"data":';
 50
 51        EXECUTE IMMEDIATE l_exec_comm
 52                        INTO l_ip_rfc;
 53        lcontext := dbms_xmlgen.newcontext(l_ip_rfc);
 54        dbms_xmlgen.setnullhandling(lcontext
 55                                         ,1);
 56        lxmldata := dbms_xmlgen.getxmltype(lcontext,dbms_xmlgen.none);
 57
 58        -- this is a XSL for JSON
 59        lxsl := '<?xml version="1.0" encoding="ISO-8859-1"?>
 60  <xsl:stylesheet version="1.0"
 61   xmlns:xsl="http://www.w3.org/1999/XSL/Transform">
 62  <xsl:output method="html"/>
 63  <xsl:template match="/">[<xsl:for-each select="/ROWSET/*">
 64   {<xsl:for-each select="./*">
 65     "<xsl:value-of select="name()"/>":"<xsl:value-of select="text()"/>"<xsl:choose>
 66      <xsl:when test="position()!= last()">,</xsl:when>
 67     </xsl:choose>
 68    </xsl:for-each>
 69   }<xsl:choose>
 70      <xsl:when test="position() != last()">,</xsl:when>
 71     </xsl:choose>
 72    </xsl:for-each>
 73  ]}]}</xsl:template></xsl:stylesheet>';
 74
 75        lhtmloutput := lxmldata.transform(xmltype(lxsl));
 76        l_ret_clob  := dbms_xmlgen.convert(lhtmloutput.getclobval(),dbms_xmlgen.ENTITY_DECODE  );
 77        l_ret_clob  := REPLACE(l_ret_clob
 78                                ,'_x0020_'
 79                                ,' ');
 80        dbms_lob.writeappend(l_header_clob
 81                                ,length(l_ret_clob)
 82                                ,l_ret_clob);
 83        RETURN l_header_clob;
 84  EXCEPTION
 85        WHEN OTHERS THEN
 86             if dbms_sql.is_open(desc_cur) then
 87                     dbms_sql.close_cursor(desc_cur);
 88             end if;
 89             n := dbms_sql.to_cursor_number(l_ip_rfc);
 90             if dbms_sql.is_open(n) then
 91                     dbms_sql.close_cursor(n);
 92             end if;
 93             raise;
 94  END refcursor_to_json;
 95  /

Function created.

demo@ORA12C>
demo@ORA12C> create or replace function foo
  2  return sys_refcursor is
  3     c sys_refcursor;
  4  begin
  5     open c for select *
  6             from dept;
  7     return c;
  8  end;
  9  /

Function created.

demo@ORA12C>
demo@ORA12C> variable x clob;
demo@ORA12C> exec :x := refcursor_to_json('foo');

PL/SQL procedure successfully completed.

demo@ORA12C> print x

X
--------------------------------------------------------------------------------
{"metadata":[{"name":"DEPTNO","type":"number"},{"name":"DNAME","type":"text"},{"
name":"LOC","type":"text"}],"data":[
 {
   "DEPTNO":"10",
   "DNAME":"ACCOUNTING",
   "LOC":"NEW YORK"
 },
 {
   "DEPTNO":"20",
   "DNAME":"RESEARCH",
   "LOC":"DALLAS"
 },
 {
   "DEPTNO":"30",
   "DNAME":"SALES",
   "LOC":"CHICAGO"
 },
 {
   "DEPTNO":"40",
   "DNAME":"OPERATIONS",
   "LOC":"BOSTON"
 }
]}]}


demo@ORA12C>