Added support for new JSON data type available in Oracle Client and Database 21
and higher.
This commit is contained in:
parent
9d4973c85d
commit
b59fe3b0be
|
@ -1176,6 +1176,14 @@ when binding data.
|
|||
by cx_Oracle.
|
||||
|
||||
|
||||
.. data:: DB_TYPE_JSON
|
||||
|
||||
Describes columns in a database that are of type JSON (with Oracle Database
|
||||
21 or later).
|
||||
|
||||
.. versionadded:: 8.1
|
||||
|
||||
|
||||
.. data:: DB_TYPE_LONG
|
||||
|
||||
Describes columns, attributes or array elements in a database that are of
|
||||
|
|
|
@ -11,6 +11,8 @@ Version 8.1 (TBD)
|
|||
#) Updated embedded ODPI-C to `version 4.1.0
|
||||
<https://oracle.github.io/odpi/doc/releasenotes.html#
|
||||
version-4-1-0-tbd>`__.
|
||||
#) Added support for new JSON data type available in Oracle Client and
|
||||
Database 21 and higher.
|
||||
#) Dropped support for Python 3.5. Added support for Python 3.9.
|
||||
#) Added internal methods for getting/setting OCI attributes that are
|
||||
otherwise not supported by cx_Oracle. These methods should only be used as
|
||||
|
|
|
@ -4,14 +4,36 @@
|
|||
Working with the JSON Data Type
|
||||
*******************************
|
||||
|
||||
Native support for JSON data was introduced in Oracle database 12c. You can use
|
||||
the relational database to store and query JSON data and benefit from the easy
|
||||
extensibility of JSON data while retaining the performance and structure of the
|
||||
relational database. JSON data is stored in the database in BLOB, CLOB or
|
||||
VARCHAR2 columns. For performance reasons, it is always a good idea to store
|
||||
JSON data in BLOB columns. To ensure that only JSON data is stored in that
|
||||
column, use a check constraint with the clause ``is JSON`` as shown in the
|
||||
following SQL to create a table containing JSON data:
|
||||
Native support for JSON data was introduced in Oracle Database 12c. You can
|
||||
use JSON with relational database features, including transactions, indexing,
|
||||
declarative querying, and views. You can project JSON data relationally,
|
||||
making it available for relational processes and tools. Also see
|
||||
:ref:`Simple Oracle Document Access (SODA) <sodausermanual>`, which allows
|
||||
access to JSON documents through a set of NoSQL-style APIs.
|
||||
|
||||
Prior to Oracle Database 21, JSON in relational tables is stored as BLOB, CLOB
|
||||
or VARCHAR2 data, allowing easy access with cx_Oracle. Oracle Database 21
|
||||
introduced a dedicated JSON data type with a new `binary storage format
|
||||
<https://blogs.oracle.com/jsondb/osonformat>`__ that improves performance and
|
||||
functionality. To use the new dedicated JSON type, the Oracle Database and
|
||||
Oracle Client libraries must be version 21, or later. Also cx_Oracle must be
|
||||
8.1, or later.
|
||||
|
||||
For more information about using JSON in Oracle Database see the
|
||||
`Database JSON Developer's Guide
|
||||
<https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=ADJSN>`__.
|
||||
|
||||
In Oracle Database 21, to create a table with a column called ``JSON_DATA`` for
|
||||
JSON data:
|
||||
|
||||
.. code-block:: sql
|
||||
|
||||
create table customers (
|
||||
id integer not null primary key,
|
||||
json_data json
|
||||
);
|
||||
|
||||
For older Oracle Database versions the syntax is:
|
||||
|
||||
.. code-block:: sql
|
||||
|
||||
|
@ -20,57 +42,269 @@ following SQL to create a table containing JSON data:
|
|||
json_data blob check (json_data is json)
|
||||
);
|
||||
|
||||
The following Python code can then be used to insert some data into the
|
||||
database:
|
||||
The check constraint with the clause ``IS JSON`` ensures only JSON data is
|
||||
stored in that column.
|
||||
|
||||
The older syntax can still be used in Oracle Database 21, however the
|
||||
recommendation is to move to the new JSON type. With the old syntax, the
|
||||
storage can be BLOB, CLOB or VARCHAR2. Of these, BLOB is preferred to avoid
|
||||
character set conversion overheads.
|
||||
|
||||
Using Oracle Database 21 and Oracle Client 21 with cx_Oracle 8.1 (or later),
|
||||
you can insert by binding as shown below:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
import datetime
|
||||
|
||||
json_data = [
|
||||
2.78,
|
||||
True,
|
||||
'Ocean Beach',
|
||||
b'Some bytes',
|
||||
{'keyA': 1, 'KeyB': 'Melbourne'},
|
||||
datetime.date.today()
|
||||
]
|
||||
|
||||
var = cursor.var(cx_Oracle.DB_TYPE_JSON)
|
||||
var.setvalue(0, json_data)
|
||||
cursor.execute("insert into customers values (:1, :2)", [123, var])
|
||||
|
||||
# or these two lines can replace the three previous lines
|
||||
cursor.setinputsizes(None, cx_Oracle.DB_TYPE_JSON)
|
||||
cursor.execute("insert into customers values (:1, :2)", [123, json_data])
|
||||
|
||||
Fetching with:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
for row in cursor.execute("SELECT c.json_data FROM customers c"):
|
||||
print(row)
|
||||
|
||||
gives output like::
|
||||
|
||||
([Decimal('2.78'), True, 'Ocean Beach',
|
||||
b'Some bytes',
|
||||
{'keyA': Decimal('1'), 'KeyB': 'Melbourne'},
|
||||
datetime.datetime(2020, 12, 2, 0, 0)],)
|
||||
|
||||
With the older BLOB storage, or to insert JSON strings, use:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
import json
|
||||
|
||||
customerData = dict(name="Rod", dept="Sales", location="Germany")
|
||||
customer_data = dict(name="Rod", dept="Sales", location="Germany")
|
||||
cursor.execute("insert into customers (id, json_data) values (:1, :2)",
|
||||
[1, json.dumps(customerData)])
|
||||
[1, json.dumps(customer_data)])
|
||||
|
||||
The data can be retrieved in its entirety using the following code:
|
||||
|
||||
IN Bind Type Mapping
|
||||
====================
|
||||
|
||||
When binding to a JSON value, the type parameter for the variable must be
|
||||
specified as :data:`cx_Oracle.DB_TYPE_JSON`. Python values are converted to
|
||||
JSON values as shown in the following table. The 'SQL Equivalent' syntax can
|
||||
be used in SQL INSERT and UPDATE statements if specific attribute types are
|
||||
needed but there is no direct mapping from Python.
|
||||
|
||||
.. list-table::
|
||||
:header-rows: 1
|
||||
:widths: 1 1 1
|
||||
:align: left
|
||||
|
||||
* - Python Type or Value
|
||||
- JSON Attribute Type or Value
|
||||
- SQL Equivalent Example
|
||||
* - None
|
||||
- null
|
||||
- NULL
|
||||
* - True
|
||||
- true
|
||||
- n/a
|
||||
* - False
|
||||
- false
|
||||
- n/a
|
||||
* - int
|
||||
- NUMBER
|
||||
- json_scalar(1)
|
||||
* - float
|
||||
- NUMBER
|
||||
- json_scalar(1)
|
||||
* - decimal.Decimal
|
||||
- NUMBER
|
||||
- json_scalar(1)
|
||||
* - str
|
||||
- VARCHAR2
|
||||
- json_scalar('String')
|
||||
* - datetime.date
|
||||
- TIMESTAMP
|
||||
- json_scalar(to_timestamp('2020-03-10', 'YYYY-MM-DD'))
|
||||
* - datetime.datetime
|
||||
- TIMESTAMP
|
||||
- json_scalar(to_timestamp('2020-03-10', 'YYYY-MM-DD'))
|
||||
* - bytes
|
||||
- RAW
|
||||
- json_scalar(utl_raw.cast_to_raw('A raw value'))
|
||||
* - list
|
||||
- Array
|
||||
- json_array(1, 2, 3 returning json)
|
||||
* - dict
|
||||
- Object
|
||||
- json_object(key 'Fred' value json_scalar(5), key 'George' value json_scalar('A string') returning json)
|
||||
* - n/a
|
||||
- CLOB
|
||||
- json_scalar(to_clob('A short CLOB'))
|
||||
* - n/a
|
||||
- BLOB
|
||||
- json_scalar(to_blob(utl_raw.cast_to_raw('A short BLOB')))
|
||||
* - n/a
|
||||
- DATE
|
||||
- json_scalar(to_date('2020-03-10', 'YYYY-MM-DD'))
|
||||
* - n/a
|
||||
- INTERVAL YEAR TO MONTH
|
||||
- json_scalar(to_yminterval('+5-9'))
|
||||
* - n/a
|
||||
- INTERVAL DAY TO SECOND
|
||||
- json_scalar(to_dsinterval('P25DT8H25M'))
|
||||
* - n/a
|
||||
- BINARY_DOUBLE
|
||||
- json_scalar(to_binary_double(25))
|
||||
* - n/a
|
||||
- BINARY_FLOAT
|
||||
- json_scalar(to_binary_float(15.5))
|
||||
|
||||
An example of creating a CLOB attribute with key ``mydocument`` in a JSON column
|
||||
using SQL is:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
import json
|
||||
|
||||
for blob, in cursor.execute("select json_data from customers"):
|
||||
data = json.loads(blob.read())
|
||||
print(data["name"]) # will print Rod
|
||||
|
||||
If only the department needs to be read, the following code can be used
|
||||
instead:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
for deptName, in cursor.execute("select c.json_data.dept from customers c"):
|
||||
print(deptName) # will print Sales
|
||||
|
||||
You can convert the data stored in relational tables into JSON data by using
|
||||
the JSON_OBJECT SQL operator. For example:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
import json
|
||||
cursor.execute("""
|
||||
select json_object(
|
||||
'id' value employee_id,
|
||||
'name' value (first_name || ' ' || last_name))
|
||||
from employees where rownum <= 3""")
|
||||
for value, in cursor:
|
||||
print(json.loads(value,))
|
||||
insert into mytab (myjsoncol) values
|
||||
(json_object(key 'mydocument' value json_scalar(to_clob(:b))
|
||||
returning json))""",
|
||||
['A short CLOB'])
|
||||
|
||||
The result is::
|
||||
When `mytab` is queried in cx_Oracle, the CLOB data will be returned as a
|
||||
Python string, as shown by the following table. Output might be like::
|
||||
|
||||
{'id': 100, 'name': 'Steven King'}
|
||||
{'id': 101, 'name': 'Neena Kochhar'}
|
||||
{'id': 102, 'name': 'Lex De Haan'}
|
||||
{mydocument: 'A short CLOB'}
|
||||
|
||||
|
||||
See `JSON Developer's Guide
|
||||
Query and OUT Bind Type Mapping
|
||||
===============================
|
||||
|
||||
When getting Oracle Database 21 JSON values from the database, the following
|
||||
attribute mapping occurs:
|
||||
|
||||
.. list-table::
|
||||
:header-rows: 1
|
||||
:widths: 1 1
|
||||
:align: left
|
||||
|
||||
* - Database JSON Attribute Type or Value
|
||||
- Python Type or Value
|
||||
* - null
|
||||
- None
|
||||
* - false
|
||||
- False
|
||||
* - true
|
||||
- True
|
||||
* - NUMBER
|
||||
- decimal.Decimal
|
||||
* - VARCHAR2
|
||||
- str
|
||||
* - RAW
|
||||
- bytes
|
||||
* - CLOB
|
||||
- str
|
||||
* - BLOB
|
||||
- bytes
|
||||
* - DATE
|
||||
- datetime.datetime
|
||||
* - TIMESTAMP
|
||||
- datetime.datetime
|
||||
* - INTERVAL YEAR TO MONTH
|
||||
- not supported
|
||||
* - INTERVAL DAY TO SECOND
|
||||
- datetime.timedelta
|
||||
* - BINARY_DOUBLE
|
||||
- float
|
||||
* - BINARY_FLOAT
|
||||
- float
|
||||
* - Arrays
|
||||
- list
|
||||
* - Objects
|
||||
- dict
|
||||
|
||||
SQL/JSON Path Expressions
|
||||
=========================
|
||||
|
||||
Oracle Database provides SQL access to JSON data using SQL/JSON path
|
||||
expressions. A path expression selects zero or more JSON values that match, or
|
||||
satisfy, it. Path expressions can use wildcards and array ranges. A simple
|
||||
path expression is ``$.friends`` which is the value of the JSON field
|
||||
``friends``.
|
||||
|
||||
For example, the previously created ``customers`` table with JSON column
|
||||
``json_data`` can be queried like:
|
||||
|
||||
.. code-block:: sql
|
||||
|
||||
select c.json_data.location FROM customers c
|
||||
|
||||
With the JSON ``'{"name":"Rod","dept":"Sales","location":"Germany"}'`` stored
|
||||
in the table, the queried value would be ``Germany``.
|
||||
|
||||
The JSON_EXISTS functions tests for the existence of a particular value within
|
||||
some JSON data. To look for JSON entries that have a ``location`` field:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
for blob, in cursor.execute("""
|
||||
select json_data
|
||||
from customers
|
||||
where json_exists(json_data, '$.location')"""):
|
||||
data = json.loads(blob.read())
|
||||
print(data)
|
||||
|
||||
This query might display::
|
||||
|
||||
{'name': 'Rod', 'dept': 'Sales', 'location': 'Germany'}
|
||||
|
||||
The SQL/JSON functions ``JSON_VALUE`` and ``JSON_QUERY`` can also be used.
|
||||
|
||||
Note that the default error-handling behavior for these functions is
|
||||
``NULL ON ERROR``, which means that no value is returned if an error occurs.
|
||||
To ensure that an error is raised, use ``ERROR ON ERROR``.
|
||||
|
||||
For more information, see `SQL/JSON Path Expressions
|
||||
<https://www.oracle.com/pls/topic/lookup?ctx=dblatest&
|
||||
id=GUID-17642E43-7D87-4590-8870-06E9FDE9A6E9>`__ for more information about
|
||||
using JSON in Oracle Database.
|
||||
id=GUID-2DC05D71-3D62-4A14-855F-76E054032494>`__
|
||||
in the Oracle JSON Developer's Guide.
|
||||
|
||||
|
||||
Accessing Relational Data as JSON
|
||||
=================================
|
||||
|
||||
In Oracle Database 12.2, or later, the `JSON_OBJECT
|
||||
<https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-1EF347AE-7FDA-4B41-AFE0-DD5A49E8B370>`__
|
||||
function is a great way to convert relational table data to JSON:
|
||||
|
||||
.. code-block:: python
|
||||
|
||||
cursor.execute("""
|
||||
select json_object('deptId' is d.department_id, 'name' is d.department_name) department
|
||||
from departments d
|
||||
where department_id < :did
|
||||
order by d.department_id""",
|
||||
[50]);
|
||||
for row in cursor:
|
||||
print(row)
|
||||
|
||||
This produces::
|
||||
|
||||
('{"deptId":10,"name":"Administration"}',)
|
||||
('{"deptId":20,"name":"Marketing"}',)
|
||||
('{"deptId":30,"name":"Purchasing"}',)
|
||||
('{"deptId":40,"name":"Human Resources"}',)
|
||||
|
|
|
@ -197,6 +197,9 @@ Python object that is returned by default. Python types can be changed with
|
|||
* - INTERVAL DAY TO SECOND
|
||||
- :attr:`cx_Oracle.DB_TYPE_INTERVAL_DS`
|
||||
- datetime.timedelta
|
||||
* - JSON
|
||||
- :attr:`cx_Oracle.DB_TYPE_JSON`
|
||||
- dict, list or a scalar value [4]_
|
||||
* - LONG
|
||||
- :attr:`cx_Oracle.DB_TYPE_LONG`
|
||||
- str
|
||||
|
@ -250,6 +253,10 @@ Python object that is returned by default. Python types can be changed with
|
|||
information present.
|
||||
.. [3] These include all user-defined types such as VARRAY, NESTED TABLE, etc.
|
||||
|
||||
.. [4] If the JSON is an object, then a dict is returned. If it is an array,
|
||||
then a list is returned. If it is a scalar value, then that particular
|
||||
scalar value is returned.
|
||||
|
||||
|
||||
.. _outputtypehandlers:
|
||||
|
||||
|
|
|
@ -0,0 +1,93 @@
|
|||
#------------------------------------------------------------------------------
|
||||
# Copyright (c) 2020, Oracle and/or its affiliates. All rights reserved.
|
||||
#------------------------------------------------------------------------------
|
||||
|
||||
#------------------------------------------------------------------------------
|
||||
# JSON.py
|
||||
# Shows some JSON features of Oracle Database 21c.
|
||||
# See https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=ADJSN
|
||||
#
|
||||
# For JSON with older databases see JSONBLOB.py
|
||||
#------------------------------------------------------------------------------
|
||||
|
||||
import sys
|
||||
import json
|
||||
import cx_Oracle
|
||||
import sample_env
|
||||
|
||||
connection = cx_Oracle.connect(sample_env.get_main_connect_string())
|
||||
|
||||
client_version = cx_Oracle.clientversion()[0]
|
||||
db_version = int(connection.version.split(".")[0])
|
||||
|
||||
# this script only works with Oracle Database 21
|
||||
|
||||
if db_version < 21:
|
||||
sys.exit("This example requires Oracle Database 21.1 or later. "
|
||||
"Try JSONBLOB.py")
|
||||
|
||||
# Create a table
|
||||
|
||||
cursor = connection.cursor()
|
||||
cursor.execute("""
|
||||
begin
|
||||
execute immediate 'drop table customers';
|
||||
exception when others then
|
||||
if sqlcode <> -942 then
|
||||
raise;
|
||||
end if;
|
||||
end;""")
|
||||
cursor.execute("""
|
||||
create table customers (
|
||||
id integer not null primary key,
|
||||
json_data json
|
||||
)""")
|
||||
|
||||
# Insert JSON data
|
||||
|
||||
data = dict(name="Rod", dept="Sales", location="Germany")
|
||||
inssql = "insert into customers values (:1, :2)"
|
||||
if client_version >= 21:
|
||||
# Take advantage of direct binding
|
||||
cursor.setinputsizes(None, cx_Oracle.DB_TYPE_JSON)
|
||||
cursor.execute(inssql, [1, data])
|
||||
else:
|
||||
# Insert the data as a JSON string
|
||||
cursor.execute(inssql, [1, json.dumps(data)])
|
||||
|
||||
# Select JSON data
|
||||
|
||||
sql = "SELECT c.json_data FROM customers c"
|
||||
if client_version >= 21:
|
||||
for j, in cursor.execute(sql):
|
||||
print(j)
|
||||
else:
|
||||
for j, in cursor.execute(sql):
|
||||
print(json.loads(j.read()))
|
||||
|
||||
# Using JSON_VALUE to extract a value from a JSON column
|
||||
|
||||
sql = """SELECT JSON_VALUE(json_data, '$.location')
|
||||
FROM customers
|
||||
OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY"""
|
||||
for r in cursor.execute(sql):
|
||||
print(r)
|
||||
|
||||
# Using dot-notation to extract a value from a JSON column
|
||||
|
||||
sql = """SELECT c.json_data.location
|
||||
FROM customers c
|
||||
OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY"""
|
||||
if client_version >= 21:
|
||||
for j, in cursor.execute(sql):
|
||||
print(j)
|
||||
else:
|
||||
for j, in cursor.execute(sql):
|
||||
print(json.loads(j.read()))
|
||||
|
||||
# Using JSON_OBJECT to extract relational data as JSON
|
||||
|
||||
sql = """SELECT JSON_OBJECT('key' IS d.dummy) dummy
|
||||
FROM dual d"""
|
||||
for r in cursor.execute(sql):
|
||||
print(r)
|
|
@ -0,0 +1,87 @@
|
|||
#------------------------------------------------------------------------------
|
||||
# Copyright (c) 2020, Oracle and/or its affiliates. All rights reserved.
|
||||
#------------------------------------------------------------------------------
|
||||
|
||||
#------------------------------------------------------------------------------
|
||||
# JSONBLOB.py
|
||||
# Shows how to use a BLOB as a JSON column store.
|
||||
#
|
||||
# Note: with Oracle Database 21c using the new JSON type is recommended
|
||||
# instead, see JSON.py
|
||||
#
|
||||
# Documentation:
|
||||
# cx_Oracle: https://cx-oracle.readthedocs.io/en/latest/user_guide/json_data_type.html
|
||||
# Oracle Database: https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=ADJSN
|
||||
##------------------------------------------------------------------------------
|
||||
|
||||
import sys
|
||||
import json
|
||||
import cx_Oracle
|
||||
import sample_env
|
||||
|
||||
connection = cx_Oracle.connect(sample_env.get_main_connect_string())
|
||||
|
||||
client_version = cx_Oracle.clientversion()[0]
|
||||
db_version = int(connection.version.split(".")[0])
|
||||
|
||||
# Minimum database vesion is 12
|
||||
if db_version < 12:
|
||||
sys.exit("This example requires Oracle Database 12.1.0.2 or later")
|
||||
|
||||
# Create a table
|
||||
|
||||
cursor = connection.cursor()
|
||||
cursor.execute("""
|
||||
begin
|
||||
execute immediate 'drop table customers';
|
||||
exception when others then
|
||||
if sqlcode <> -942 then
|
||||
raise;
|
||||
end if;
|
||||
end;""")
|
||||
cursor.execute("""
|
||||
create table customers (
|
||||
id integer not null primary key,
|
||||
json_data blob check (json_data is json)
|
||||
) lob (json_data) store as (cache)""")
|
||||
|
||||
# Insert JSON data
|
||||
|
||||
data = dict(name="Rod", dept="Sales", location="Germany")
|
||||
inssql = "insert into customers values (:1, :2)"
|
||||
if client_version >= 21 and db_version >= 21:
|
||||
# Take advantage of direct binding
|
||||
cursor.setinputsizes(None, cx_Oracle.DB_TYPE_JSON)
|
||||
cursor.execute(inssql, [1, data])
|
||||
else:
|
||||
# Insert the data as a JSON string
|
||||
cursor.execute(inssql, [1, json.dumps(data)])
|
||||
|
||||
# Select JSON data
|
||||
|
||||
sql = "SELECT c.json_data FROM customers c"
|
||||
for j, in cursor.execute(sql):
|
||||
print(json.loads(j.read()))
|
||||
|
||||
# Using JSON_VALUE to extract a value from a JSON column
|
||||
|
||||
sql = """SELECT JSON_VALUE(json_data, '$.location')
|
||||
FROM customers
|
||||
OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY"""
|
||||
for r in cursor.execute(sql):
|
||||
print(r)
|
||||
|
||||
# Using dot-notation to extract a value from a JSON (BLOB storage) column
|
||||
|
||||
sql = """SELECT c.json_data.location
|
||||
FROM customers c
|
||||
OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY"""
|
||||
for j, in cursor.execute(sql):
|
||||
print(j)
|
||||
|
||||
# Using JSON_OBJECT to extract relational data as JSON
|
||||
|
||||
sql = """SELECT JSON_OBJECT('key' IS d.dummy) dummy
|
||||
FROM dual d"""
|
||||
for r in cursor.execute(sql):
|
||||
print(r)
|
|
@ -230,6 +230,8 @@ cxoDbType *cxoDbType_fromTransformNum(cxoTransformNum transformNum)
|
|||
return cxoDbTypeTimestampLTZ;
|
||||
case CXO_TRANSFORM_TIMESTAMP_TZ:
|
||||
return cxoDbTypeTimestampTZ;
|
||||
case CXO_TRANSFORM_JSON:
|
||||
return cxoDbTypeJson;
|
||||
default:
|
||||
break;
|
||||
}
|
||||
|
|
|
@ -0,0 +1,269 @@
|
|||
//-----------------------------------------------------------------------------
|
||||
// Copyright (c) 2020, Oracle and/or its affiliates. All rights reserved.
|
||||
//-----------------------------------------------------------------------------
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// cxoJsonBuffer.c
|
||||
// Defines buffer structure and routines for populating JSON values. These
|
||||
// are used to translate Python objects (scalars, dictionaries and lists) into
|
||||
// JSON values stored in the database.
|
||||
//-----------------------------------------------------------------------------
|
||||
|
||||
#include "cxoModule.h"
|
||||
|
||||
#define CXO_JSON_ENCODING "UTF-8"
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// cxoJsonBuffer_getBuffer()
|
||||
// Acquire a new buffer from the array of buffers. If one is not available,
|
||||
// more space is allocated in chunks.
|
||||
//-----------------------------------------------------------------------------
|
||||
static int cxoJsonBuffer_getBuffer(cxoJsonBuffer *buf, cxoBuffer **buffer)
|
||||
{
|
||||
cxoBuffer *tempBuffers;
|
||||
|
||||
if (buf->numBuffers == buf->allocatedBuffers) {
|
||||
buf->allocatedBuffers += 16;
|
||||
tempBuffers = PyMem_Realloc(buf->buffers,
|
||||
buf->allocatedBuffers * sizeof(cxoBuffer));
|
||||
if (!tempBuffers) {
|
||||
PyErr_NoMemory();
|
||||
return -1;
|
||||
}
|
||||
buf->buffers = tempBuffers;
|
||||
}
|
||||
*buffer = &buf->buffers[buf->numBuffers++];
|
||||
|
||||
return 0;
|
||||
}
|
||||
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// cxoJsonBuffer_populateNode()
|
||||
// Populate a particular node with the value of the Python object.
|
||||
//-----------------------------------------------------------------------------
|
||||
static int cxoJsonBuffer_populateNode(cxoJsonBuffer *buf, dpiJsonNode *node,
|
||||
PyObject *value)
|
||||
{
|
||||
cxoTransformNum transformNum;
|
||||
PyObject *childValue, *key;
|
||||
cxoBuffer *tempBuffer;
|
||||
Py_ssize_t pos, size;
|
||||
dpiJsonArray *array;
|
||||
dpiJsonObject *obj;
|
||||
char message[250];
|
||||
uint32_t i;
|
||||
|
||||
// handle NULL values
|
||||
if (value == Py_None) {
|
||||
node->oracleTypeNum = DPI_ORACLE_TYPE_NONE;
|
||||
node->nativeTypeNum = DPI_NATIVE_TYPE_NULL;
|
||||
return 0;
|
||||
}
|
||||
|
||||
// handle arrays
|
||||
if (PyList_Check(value)) {
|
||||
|
||||
// initialize array
|
||||
node->oracleTypeNum = DPI_ORACLE_TYPE_JSON_ARRAY;
|
||||
node->nativeTypeNum = DPI_NATIVE_TYPE_JSON_ARRAY;
|
||||
array = &node->value->asJsonArray;
|
||||
array->numElements = (uint32_t) PyList_GET_SIZE(value);
|
||||
array->elements = PyMem_Calloc(array->numElements,
|
||||
sizeof(dpiJsonNode));
|
||||
array->elementValues = PyMem_Calloc(array->numElements,
|
||||
sizeof(dpiDataBuffer));
|
||||
if (!array->elements || !array->elementValues) {
|
||||
PyErr_NoMemory();
|
||||
return -1;
|
||||
}
|
||||
|
||||
// process each element of the array
|
||||
for (i = 0; i < array->numElements; i++) {
|
||||
childValue = PyList_GET_ITEM(value, i);
|
||||
array->elements[i].value = &array->elementValues[i];
|
||||
if (cxoJsonBuffer_populateNode(buf, &array->elements[i],
|
||||
childValue) < 0)
|
||||
return -1;
|
||||
}
|
||||
|
||||
return 0;
|
||||
}
|
||||
|
||||
// handle dictionaries
|
||||
if (PyDict_Check(value)) {
|
||||
|
||||
// initialize object
|
||||
node->oracleTypeNum = DPI_ORACLE_TYPE_JSON_OBJECT;
|
||||
node->nativeTypeNum = DPI_NATIVE_TYPE_JSON_OBJECT;
|
||||
obj = &node->value->asJsonObject;
|
||||
size = PyDict_Size(value);
|
||||
if (size < 0)
|
||||
return -1;
|
||||
obj->numFields = (uint32_t) size;
|
||||
obj->fieldNames = PyMem_Calloc(obj->numFields, sizeof(char*));
|
||||
obj->fieldNameLengths = PyMem_Calloc(obj->numFields, sizeof(uint32_t));
|
||||
obj->fields = PyMem_Calloc(obj->numFields, sizeof(dpiJsonNode));
|
||||
obj->fieldValues = PyMem_Calloc(obj->numFields,
|
||||
sizeof(dpiDataBuffer));
|
||||
if (!obj->fieldNames || !obj->fieldNameLengths || !obj->fields ||
|
||||
!obj->fieldValues) {
|
||||
PyErr_NoMemory();
|
||||
return -1;
|
||||
}
|
||||
|
||||
// process each entry in the dictionary
|
||||
i = 0;
|
||||
pos = 0;
|
||||
while (PyDict_Next(value, &pos, &key, &childValue)) {
|
||||
if (cxoJsonBuffer_getBuffer(buf, &tempBuffer) < 0)
|
||||
return -1;
|
||||
if (cxoBuffer_fromObject(tempBuffer, key, CXO_JSON_ENCODING) < 0)
|
||||
return -1;
|
||||
obj->fields[i].value = &obj->fieldValues[i];
|
||||
obj->fieldNames[i] = (char*) tempBuffer->ptr;
|
||||
obj->fieldNameLengths[i] = tempBuffer->size;
|
||||
if (cxoJsonBuffer_populateNode(buf, &obj->fields[i],
|
||||
childValue) < 0)
|
||||
return -1;
|
||||
i++;
|
||||
}
|
||||
|
||||
return 0;
|
||||
}
|
||||
|
||||
// handle scalar values
|
||||
tempBuffer = NULL;
|
||||
transformNum = cxoTransform_getNumFromPythonValue(value, 1);
|
||||
switch (transformNum) {
|
||||
|
||||
// strings and bytes must have a buffer made available for them to
|
||||
// store a reference to the object and the actual pointer and length;
|
||||
// numbers are converted to a string in order to prevent precision loss
|
||||
case CXO_TRANSFORM_STRING:
|
||||
case CXO_TRANSFORM_BINARY:
|
||||
case CXO_TRANSFORM_INT:
|
||||
case CXO_TRANSFORM_FLOAT:
|
||||
case CXO_TRANSFORM_DECIMAL:
|
||||
if (cxoJsonBuffer_getBuffer(buf, &tempBuffer) < 0)
|
||||
return -1;
|
||||
break;
|
||||
|
||||
// swap CXO_TRANSFORM_DATETIME to CXO_TRANSFORM_TIMESTAMP to preserve
|
||||
// fractional seconds
|
||||
case CXO_TRANSFORM_DATETIME:
|
||||
transformNum = CXO_TRANSFORM_TIMESTAMP;
|
||||
break;
|
||||
|
||||
// all other types do not need any special processing
|
||||
case CXO_TRANSFORM_BOOLEAN:
|
||||
case CXO_TRANSFORM_DATE:
|
||||
case CXO_TRANSFORM_TIMEDELTA:
|
||||
break;
|
||||
|
||||
// any other type is not currently supported
|
||||
default:
|
||||
snprintf(message, sizeof(message), "Python type %s not supported.",
|
||||
Py_TYPE(value)->tp_name);
|
||||
cxoError_raiseFromString(cxoNotSupportedErrorException, message);
|
||||
return -1;
|
||||
}
|
||||
|
||||
// transform the Python value into the Oracle value
|
||||
cxoTransform_getTypeInfo(transformNum, &node->oracleTypeNum,
|
||||
&node->nativeTypeNum);
|
||||
if (cxoTransform_fromPython(transformNum, &node->nativeTypeNum, value,
|
||||
node->value, tempBuffer, CXO_JSON_ENCODING, CXO_JSON_ENCODING,
|
||||
NULL, 0) < 0)
|
||||
return -1;
|
||||
|
||||
return 0;
|
||||
}
|
||||
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// cxoJsonBuffer_freeNode()
|
||||
// Frees any arrays allocated earlier for the specified node.
|
||||
//-----------------------------------------------------------------------------
|
||||
static void cxoJsonBuffer_freeNode(dpiJsonNode *node)
|
||||
{
|
||||
dpiJsonArray *array;
|
||||
dpiJsonObject *obj;
|
||||
uint32_t i;
|
||||
|
||||
switch (node->nativeTypeNum) {
|
||||
case DPI_NATIVE_TYPE_JSON_ARRAY:
|
||||
array = &node->value->asJsonArray;
|
||||
if (array->elements) {
|
||||
for (i = 0; i < array->numElements; i++) {
|
||||
if (array->elements[i].value)
|
||||
cxoJsonBuffer_freeNode(&array->elements[i]);
|
||||
}
|
||||
PyMem_Free(array->elements);
|
||||
array->elements = NULL;
|
||||
}
|
||||
if (array->elementValues) {
|
||||
PyMem_Free(array->elementValues);
|
||||
array->elementValues = NULL;
|
||||
}
|
||||
break;
|
||||
case DPI_NATIVE_TYPE_JSON_OBJECT:
|
||||
obj = &node->value->asJsonObject;
|
||||
if (obj->fields) {
|
||||
for (i = 0; i < obj->numFields; i++) {
|
||||
if (obj->fields[i].value)
|
||||
cxoJsonBuffer_freeNode(&obj->fields[i]);
|
||||
}
|
||||
PyMem_Free(obj->fields);
|
||||
obj->fields = NULL;
|
||||
}
|
||||
if (obj->fieldNames) {
|
||||
PyMem_Free(obj->fieldNames);
|
||||
obj->fieldNames = NULL;
|
||||
}
|
||||
if (obj->fieldNameLengths) {
|
||||
PyMem_Free(obj->fieldNameLengths);
|
||||
obj->fieldNameLengths = NULL;
|
||||
}
|
||||
if (obj->fieldValues) {
|
||||
PyMem_Free(obj->fieldValues);
|
||||
obj->fieldValues = NULL;
|
||||
}
|
||||
break;
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// cxoJsonBuffer_free()
|
||||
// Frees any memory allocated for the JSON buffer.
|
||||
//-----------------------------------------------------------------------------
|
||||
void cxoJsonBuffer_free(cxoJsonBuffer *buf)
|
||||
{
|
||||
uint32_t i;
|
||||
|
||||
if (buf->buffers) {
|
||||
for (i = 0; i < buf->numBuffers; i++)
|
||||
cxoBuffer_clear(&buf->buffers[i]);
|
||||
PyMem_Free(buf->buffers);
|
||||
buf->buffers = NULL;
|
||||
}
|
||||
cxoJsonBuffer_freeNode(&buf->topNode);
|
||||
}
|
||||
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// cxoJsonBuffer_fromObject()
|
||||
// Populate the JSON buffer from a Python object.
|
||||
//-----------------------------------------------------------------------------
|
||||
int cxoJsonBuffer_fromObject(cxoJsonBuffer *buf, PyObject *obj)
|
||||
{
|
||||
// initialize JSON buffer structure
|
||||
buf->topNode.value = &buf->topNodeBuffer;
|
||||
buf->allocatedBuffers = 0;
|
||||
buf->numBuffers = 0;
|
||||
buf->buffers = NULL;
|
||||
|
||||
// populate the top level node
|
||||
return cxoJsonBuffer_populateNode(buf, &buf->topNode, obj);
|
||||
}
|
|
@ -76,6 +76,7 @@ cxoDbType *cxoDbTypeCursor = NULL;
|
|||
cxoDbType *cxoDbTypeDate = NULL;
|
||||
cxoDbType *cxoDbTypeIntervalDS = NULL;
|
||||
cxoDbType *cxoDbTypeIntervalYM = NULL;
|
||||
cxoDbType *cxoDbTypeJson = NULL;
|
||||
cxoDbType *cxoDbTypeLong = NULL;
|
||||
cxoDbType *cxoDbTypeLongRaw = NULL;
|
||||
cxoDbType *cxoDbTypeNchar = NULL;
|
||||
|
@ -495,6 +496,8 @@ static PyObject *cxoModule_initialize(void)
|
|||
CXO_TRANSFORM_TIMEDELTA, &cxoDbTypeIntervalDS)
|
||||
CXO_ADD_DB_TYPE(DPI_ORACLE_TYPE_INTERVAL_YM, "DB_TYPE_INTERVAL_YM",
|
||||
CXO_TRANSFORM_UNSUPPORTED, &cxoDbTypeIntervalYM)
|
||||
CXO_ADD_DB_TYPE(DPI_ORACLE_TYPE_JSON, "DB_TYPE_JSON",
|
||||
CXO_TRANSFORM_JSON, &cxoDbTypeJson)
|
||||
CXO_ADD_DB_TYPE(DPI_ORACLE_TYPE_LONG_VARCHAR, "DB_TYPE_LONG",
|
||||
CXO_TRANSFORM_LONG_STRING, &cxoDbTypeLong)
|
||||
CXO_ADD_DB_TYPE(DPI_ORACLE_TYPE_LONG_RAW, "DB_TYPE_LONG_RAW",
|
||||
|
|
|
@ -38,6 +38,7 @@ typedef struct cxoDeqOptions cxoDeqOptions;
|
|||
typedef struct cxoEnqOptions cxoEnqOptions;
|
||||
typedef struct cxoError cxoError;
|
||||
typedef struct cxoFuture cxoFuture;
|
||||
typedef struct cxoJsonBuffer cxoJsonBuffer;
|
||||
typedef struct cxoLob cxoLob;
|
||||
typedef struct cxoMessage cxoMessage;
|
||||
typedef struct cxoMessageQuery cxoMessageQuery;
|
||||
|
@ -119,6 +120,7 @@ extern cxoDbType *cxoDbTypeCursor;
|
|||
extern cxoDbType *cxoDbTypeDate;
|
||||
extern cxoDbType *cxoDbTypeIntervalDS;
|
||||
extern cxoDbType *cxoDbTypeIntervalYM;
|
||||
extern cxoDbType *cxoDbTypeJson;
|
||||
extern cxoDbType *cxoDbTypeLong;
|
||||
extern cxoDbType *cxoDbTypeLongRaw;
|
||||
extern cxoDbType *cxoDbTypeNchar;
|
||||
|
@ -184,6 +186,7 @@ typedef enum {
|
|||
CXO_TRANSFORM_TIMESTAMP,
|
||||
CXO_TRANSFORM_TIMESTAMP_LTZ,
|
||||
CXO_TRANSFORM_TIMESTAMP_TZ,
|
||||
CXO_TRANSFORM_JSON,
|
||||
CXO_TRANSFORM_UNSUPPORTED
|
||||
} cxoTransformNum;
|
||||
|
||||
|
@ -286,6 +289,14 @@ struct cxoFuture {
|
|||
PyObject_HEAD
|
||||
};
|
||||
|
||||
struct cxoJsonBuffer {
|
||||
dpiJsonNode topNode;
|
||||
dpiDataBuffer topNodeBuffer;
|
||||
uint32_t allocatedBuffers;
|
||||
uint32_t numBuffers;
|
||||
cxoBuffer *buffers;
|
||||
};
|
||||
|
||||
struct cxoLob {
|
||||
PyObject_HEAD
|
||||
cxoConnection *connection;
|
||||
|
@ -497,6 +508,9 @@ int cxoError_raiseFromInfo(dpiErrorInfo *errorInfo);
|
|||
PyObject *cxoError_raiseFromString(PyObject *exceptionType,
|
||||
const char *message);
|
||||
|
||||
void cxoJsonBuffer_free(cxoJsonBuffer *buf);
|
||||
int cxoJsonBuffer_fromObject(cxoJsonBuffer *buf, PyObject *obj);
|
||||
|
||||
PyObject *cxoLob_new(cxoConnection *connection, cxoDbType *dbType,
|
||||
dpiLob *handle);
|
||||
|
||||
|
|
|
@ -30,6 +30,13 @@ static Py_ssize_t cxoTransform_calculateSize(PyObject *value,
|
|||
static cxoTransformNum cxoTransform_getNumFromPythonType(PyTypeObject *type);
|
||||
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// Forward declarations
|
||||
//-----------------------------------------------------------------------------
|
||||
static PyObject *cxoTransform_toPythonFromJson(cxoConnection *connection,
|
||||
dpiJsonNode *node, const char *encodingErrors);
|
||||
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// Types
|
||||
//-----------------------------------------------------------------------------
|
||||
|
@ -186,6 +193,11 @@ static const cxoTransform cxoAllTransforms[] = {
|
|||
CXO_TRANSFORM_TIMESTAMP_TZ,
|
||||
DPI_ORACLE_TYPE_TIMESTAMP_TZ,
|
||||
DPI_NATIVE_TYPE_TIMESTAMP
|
||||
},
|
||||
{
|
||||
CXO_TRANSFORM_JSON,
|
||||
DPI_ORACLE_TYPE_JSON,
|
||||
DPI_NATIVE_TYPE_JSON
|
||||
}
|
||||
};
|
||||
|
||||
|
@ -233,6 +245,7 @@ int cxoTransform_fromPython(cxoTransformNum transformNum,
|
|||
dpiDataBuffer *dbValue, cxoBuffer *buffer, const char *encoding,
|
||||
const char *nencoding, cxoVar *var, uint32_t arrayPos)
|
||||
{
|
||||
cxoJsonBuffer jsonBuffer;
|
||||
dpiIntervalDS *interval;
|
||||
PyDateTime_Delta *delta;
|
||||
int32_t deltaSeconds;
|
||||
|
@ -396,6 +409,17 @@ int cxoTransform_fromPython(cxoTransformNum transformNum,
|
|||
interval->fseconds =
|
||||
PyDateTime_DELTA_GET_MICROSECONDS(delta) * 1000;
|
||||
return 0;
|
||||
case CXO_TRANSFORM_JSON:
|
||||
status = cxoJsonBuffer_fromObject(&jsonBuffer, pyValue);
|
||||
if (status < 0) {
|
||||
cxoJsonBuffer_free(&jsonBuffer);
|
||||
return -1;
|
||||
}
|
||||
status = dpiJson_setValue(dbValue->asJson, &jsonBuffer.topNode);
|
||||
cxoJsonBuffer_free(&jsonBuffer);
|
||||
if (status < 0)
|
||||
return cxoError_raiseAndReturnInt();
|
||||
return 0;
|
||||
default:
|
||||
break;
|
||||
}
|
||||
|
@ -495,6 +519,8 @@ cxoTransformNum cxoTransform_getNumFromDataTypeInfo(dpiDataTypeInfo *info)
|
|||
return CXO_TRANSFORM_LONG_BINARY;
|
||||
case DPI_ORACLE_TYPE_BOOLEAN:
|
||||
return CXO_TRANSFORM_BOOLEAN;
|
||||
case DPI_ORACLE_TYPE_JSON:
|
||||
return CXO_TRANSFORM_JSON;
|
||||
default:
|
||||
break;
|
||||
}
|
||||
|
@ -772,6 +798,7 @@ PyObject *cxoTransform_toPython(cxoTransformNum transformNum,
|
|||
PyObject *stringObj, *result;
|
||||
dpiIntervalDS *intervalDS;
|
||||
dpiTimestamp *timestamp;
|
||||
dpiJsonNode *jsonNode;
|
||||
uint32_t rowidLength;
|
||||
cxoDbType *dbType;
|
||||
const char *rowid;
|
||||
|
@ -857,6 +884,12 @@ PyObject *cxoTransform_toPython(cxoTransformNum transformNum,
|
|||
return cxoError_raiseAndReturnNull();
|
||||
return PyUnicode_Decode(rowid, rowidLength,
|
||||
connection->encodingInfo.encoding, NULL);
|
||||
case CXO_TRANSFORM_JSON:
|
||||
if (dpiJson_getValue(dbValue->asJson,
|
||||
DPI_JSON_OPT_NUMBER_AS_STRING, &jsonNode) < 0)
|
||||
return cxoError_raiseAndReturnNull();
|
||||
return cxoTransform_toPythonFromJson(connection, jsonNode,
|
||||
encodingErrors);
|
||||
case CXO_TRANSFORM_TIMEDELTA:
|
||||
intervalDS = &dbValue->asIntervalDS;
|
||||
seconds = intervalDS->hours * 60 * 60 + intervalDS->minutes * 60 +
|
||||
|
@ -870,3 +903,84 @@ PyObject *cxoTransform_toPython(cxoTransformNum transformNum,
|
|||
return cxoError_raiseFromString(cxoNotSupportedErrorException,
|
||||
"Database value cannot be converted to a Python value");
|
||||
}
|
||||
|
||||
|
||||
//-----------------------------------------------------------------------------
|
||||
// cxoTransform_toPythonFromJson()
|
||||
// Transforms a JSON node to its equivalent Python value.
|
||||
//-----------------------------------------------------------------------------
|
||||
static PyObject *cxoTransform_toPythonFromJson(cxoConnection *connection,
|
||||
dpiJsonNode *node, const char *encodingErrors)
|
||||
{
|
||||
PyObject *result, *temp, *name;
|
||||
cxoTransformNum transformNum;
|
||||
dpiJsonArray *array;
|
||||
dpiJsonObject *obj;
|
||||
uint32_t i;
|
||||
|
||||
// null is a special case
|
||||
if (node->nativeTypeNum == DPI_NATIVE_TYPE_NULL)
|
||||
Py_RETURN_NONE;
|
||||
|
||||
switch (node->oracleTypeNum) {
|
||||
case DPI_ORACLE_TYPE_NUMBER:
|
||||
transformNum = (node->nativeTypeNum == DPI_NATIVE_TYPE_DOUBLE) ?
|
||||
CXO_TRANSFORM_NATIVE_DOUBLE : CXO_TRANSFORM_DECIMAL;
|
||||
break;
|
||||
case DPI_ORACLE_TYPE_VARCHAR:
|
||||
transformNum = CXO_TRANSFORM_STRING;
|
||||
break;
|
||||
case DPI_ORACLE_TYPE_RAW:
|
||||
transformNum = CXO_TRANSFORM_BINARY;
|
||||
break;
|
||||
case DPI_ORACLE_TYPE_DATE:
|
||||
case DPI_ORACLE_TYPE_TIMESTAMP:
|
||||
transformNum = CXO_TRANSFORM_DATETIME;
|
||||
break;
|
||||
case DPI_ORACLE_TYPE_BOOLEAN:
|
||||
transformNum = CXO_TRANSFORM_BOOLEAN;
|
||||
break;
|
||||
case DPI_ORACLE_TYPE_INTERVAL_DS:
|
||||
transformNum = CXO_TRANSFORM_TIMEDELTA;
|
||||
break;
|
||||
case DPI_ORACLE_TYPE_JSON_OBJECT:
|
||||
obj = &node->value->asJsonObject;
|
||||
result = PyDict_New();
|
||||
for (i = 0; i < obj->numFields; i++) {
|
||||
name = PyUnicode_DecodeUTF8(obj->fieldNames[i],
|
||||
obj->fieldNameLengths[i], NULL);
|
||||
if (!name)
|
||||
return NULL;
|
||||
temp = cxoTransform_toPythonFromJson(connection,
|
||||
&obj->fields[i], encodingErrors);
|
||||
if (!temp)
|
||||
return NULL;
|
||||
if (PyDict_SetItem(result, name, temp) < 0) {
|
||||
Py_DECREF(name);
|
||||
Py_DECREF(temp);
|
||||
return NULL;
|
||||
}
|
||||
Py_DECREF(name);
|
||||
Py_DECREF(temp);
|
||||
}
|
||||
return result;
|
||||
case DPI_ORACLE_TYPE_JSON_ARRAY:
|
||||
array = &node->value->asJsonArray;
|
||||
result = PyList_New(array->numElements);
|
||||
for (i = 0; i < array->numElements; i++) {
|
||||
temp = cxoTransform_toPythonFromJson(connection,
|
||||
&array->elements[i], encodingErrors);
|
||||
if (!temp) {
|
||||
Py_DECREF(result);
|
||||
return NULL;
|
||||
}
|
||||
PyList_SET_ITEM(result, i, temp);
|
||||
}
|
||||
return result;
|
||||
default:
|
||||
transformNum = CXO_TRANSFORM_UNSUPPORTED;
|
||||
}
|
||||
|
||||
return cxoTransform_toPython(transformNum, connection, NULL,
|
||||
node->value, encodingErrors);
|
||||
}
|
||||
|
|
|
@ -252,6 +252,25 @@ create table &main_user..PlsqlSessionCallbacks (
|
|||
)
|
||||
/
|
||||
|
||||
declare
|
||||
t_Version number;
|
||||
begin
|
||||
|
||||
select to_number(substr(version, 1, instr(version, '.') - 1))
|
||||
into t_Version
|
||||
from product_component_version
|
||||
where product like 'Oracle Database%';
|
||||
|
||||
if t_Version >= 21 then
|
||||
execute immediate 'create table &main_user..TestJson (' ||
|
||||
' IntCol number(9) not null,' ||
|
||||
' JsonCol json not null' ||
|
||||
')';
|
||||
end if;
|
||||
|
||||
end;
|
||||
/
|
||||
|
||||
-- create queue table and queues for testing advanced queuing
|
||||
begin
|
||||
dbms_aqadm.create_queue_table('&main_user..BOOK_QUEUE_TAB',
|
||||
|
|
|
@ -0,0 +1,170 @@
|
|||
#------------------------------------------------------------------------------
|
||||
# Copyright (c) 2020, Oracle and/or its affiliates. All rights reserved.
|
||||
#------------------------------------------------------------------------------
|
||||
|
||||
"""
|
||||
3500 - Module for testing the JSON data type.
|
||||
"""
|
||||
|
||||
import cx_Oracle as oracledb
|
||||
import base
|
||||
import datetime
|
||||
import decimal
|
||||
import unittest
|
||||
|
||||
@unittest.skipUnless(base.get_client_version() >= (21, 0),
|
||||
"unsupported client")
|
||||
@unittest.skipUnless(base.get_server_version() >= (21, 0),
|
||||
"unsupported server")
|
||||
class TestCase(base.BaseTestCase):
|
||||
|
||||
json_data = [
|
||||
True,
|
||||
False,
|
||||
'String',
|
||||
b'Some Bytes',
|
||||
{},
|
||||
{"name": None},
|
||||
{"name": "John"},
|
||||
{"age": 30},
|
||||
{"Permanent": True},
|
||||
{
|
||||
"employee": {
|
||||
"name":"John",
|
||||
"age": 30,
|
||||
"city": "Delhi",
|
||||
"Parmanent": True
|
||||
}
|
||||
},
|
||||
{
|
||||
"employees": ["John", "Matthew", "James"]
|
||||
},
|
||||
{
|
||||
"employees": [
|
||||
{
|
||||
"employee1": {"name": "John", "city": "Delhi"}
|
||||
},
|
||||
{
|
||||
"employee2": {"name": "Matthew", "city": "Mumbai"}
|
||||
},
|
||||
{
|
||||
"employee3": {"name": "James", "city": "Bangalore"}
|
||||
}
|
||||
]
|
||||
}
|
||||
]
|
||||
|
||||
def __bind_scalar_as_json(self, data):
|
||||
self.cursor.execute("truncate table TestJson")
|
||||
out_var = self.cursor.var(oracledb.DB_TYPE_JSON,
|
||||
arraysize=len(data))
|
||||
self.cursor.setinputsizes(None, oracledb.DB_TYPE_JSON, out_var)
|
||||
bind_data = list(enumerate(data))
|
||||
self.cursor.executemany("""
|
||||
insert into TestJson values (:1, :2)
|
||||
returning JsonCol into :json_out""", bind_data)
|
||||
self.connection.commit()
|
||||
self.assertEqual(out_var.values, [[v] for v in data])
|
||||
|
||||
def test_3500_insert_and_fetch_single_json(self):
|
||||
"3500 - insert and fetch single row with JSON"
|
||||
self.cursor.execute("truncate table TestJson")
|
||||
self.cursor.setinputsizes(None, oracledb.DB_TYPE_JSON)
|
||||
self.cursor.execute("insert into TestJson values (:1, :2)",
|
||||
[1, self.json_data])
|
||||
self.cursor.execute("select JsonCol from TestJson")
|
||||
result, = self.cursor.fetchone()
|
||||
self.assertEqual(result, self.json_data)
|
||||
|
||||
def test_3501_execute_with_dml_returning(self):
|
||||
"3502 - inserting single rows with JSON and DML returning"
|
||||
json_val = self.json_data[11]
|
||||
self.cursor.execute("truncate table TestJson")
|
||||
json_out = self.cursor.var(oracledb.DB_TYPE_JSON)
|
||||
self.cursor.setinputsizes(None, oracledb.DB_TYPE_JSON, json_out)
|
||||
self.cursor.execute("""
|
||||
insert into TestJson values (:1, :2)
|
||||
returning JsonCol into :json_out""",
|
||||
[1, json_val])
|
||||
self.assertEqual(json_out.getvalue(0), [json_val])
|
||||
|
||||
def test_3502_insert_and_fetch_multiple_json(self):
|
||||
"3502 - insert and fetch multiple rows with JSON"
|
||||
self.cursor.execute("truncate table TestJson")
|
||||
self.cursor.setinputsizes(None, oracledb.DB_TYPE_JSON)
|
||||
data = list(enumerate(self.json_data))
|
||||
self.cursor.executemany("insert into TestJson values(:1, :2)", data)
|
||||
self.cursor.execute("select * from TestJson")
|
||||
fetched_data = self.cursor.fetchall()
|
||||
self.assertEqual(fetched_data, data)
|
||||
|
||||
def test_3503_executemany_with_dml_returning(self):
|
||||
"3503 - inserting multiple rows with JSON and DML returning"
|
||||
self.cursor.execute("truncate table TestJson")
|
||||
int_values = [i for i in range(len(self.json_data))]
|
||||
out_int_var = self.cursor.var(int, arraysize=len(int_values))
|
||||
out_json_var = self.cursor.var(oracledb.DB_TYPE_JSON,
|
||||
arraysize=len(int_values))
|
||||
self.cursor.setinputsizes(None, oracledb.DB_TYPE_JSON, out_int_var,
|
||||
out_json_var)
|
||||
data = list(zip(int_values, self.json_data))
|
||||
self.cursor.executemany("""
|
||||
insert into TestJson
|
||||
values(:int_val, :json_val)
|
||||
returning IntCol, JsonCol into :int_var, :json_var""", data)
|
||||
self.assertEqual(out_int_var.values, [[v] for v in int_values])
|
||||
self.assertEqual(out_json_var.values, [[v] for v in self.json_data])
|
||||
|
||||
def test_3504_boolean(self):
|
||||
"3509 - test binding boolean values as scalar JSON values"
|
||||
data = [
|
||||
True,
|
||||
False,
|
||||
True,
|
||||
True,
|
||||
False,
|
||||
True
|
||||
]
|
||||
self.__bind_scalar_as_json(data)
|
||||
|
||||
def test_3505_strings_and_bytes(self):
|
||||
"3509 - test binding strings/bytes values as scalar JSON values"
|
||||
data = [
|
||||
"String 1",
|
||||
b"A raw value",
|
||||
"A much longer string",
|
||||
b"A much longer RAW value",
|
||||
"Short string",
|
||||
b"Y"
|
||||
]
|
||||
self.__bind_scalar_as_json(data)
|
||||
|
||||
def test_3506_datetime(self):
|
||||
"3506 - test binding dates/intervals as scalar JSON values"
|
||||
data = [
|
||||
datetime.datetime.today(),
|
||||
datetime.datetime(2004, 2, 1, 3, 4, 5),
|
||||
datetime.datetime(2020, 12, 2, 13, 29, 14),
|
||||
datetime.timedelta(8.5),
|
||||
datetime.datetime(2002, 12, 13, 9, 36, 0),
|
||||
oracledb.Timestamp(2002, 12, 13, 9, 36, 0),
|
||||
datetime.datetime(2002, 12, 13)
|
||||
]
|
||||
self.__bind_scalar_as_json(data)
|
||||
|
||||
def test_3507_bind_number(self):
|
||||
"3507 - test binding number in json values"
|
||||
data = [
|
||||
0,
|
||||
1,
|
||||
25.25,
|
||||
6088343244,
|
||||
-9999999999999999999,
|
||||
decimal.Decimal("0.25"),
|
||||
decimal.Decimal("10.25"),
|
||||
decimal.Decimal("319438950232418390.273596")
|
||||
]
|
||||
self.__bind_scalar_as_json(data)
|
||||
|
||||
if __name__ == "__main__":
|
||||
base.run_test_cases()
|
Loading…
Reference in New Issue