Skip to content

Commit

Permalink
Update documentation and samples.
Browse files Browse the repository at this point in the history
  • Loading branch information
anthony-tuininga committed Jul 4, 2024
1 parent 3eee245 commit 00f5a58
Show file tree
Hide file tree
Showing 5 changed files with 225 additions and 4 deletions.
10 changes: 7 additions & 3 deletions doc/src/user_guide/appendix_a.rst
Original file line number Diff line number Diff line change
Expand Up @@ -187,7 +187,7 @@ see :ref:`driverdiff` and :ref:`compatibility`.
- Yes
- Yes
* - SQL execution (see :ref:`sqlexecution`)
- Yes - bind and fetch all types except BFILE and JSON
- Yes
- Yes
- Yes
* - PL/SQL execution (see :ref:`plsqlexecution`)
Expand Down Expand Up @@ -238,6 +238,10 @@ see :ref:`driverdiff` and :ref:`compatibility`.
- No
- Yes
- Yes
* - Oracle Database 23ai JSON-Relational Duality Views (see :ref:`jsondualityviews`)
- Yes
- Yes
- No
* - Continuous Query Notification (CQN) (see :ref:`cqn`)
- No
- Yes
Expand Down Expand Up @@ -454,8 +458,8 @@ values.
- :ref:`oracledb.LOB <lobobj>`, bytes, str
* - BFILE
- :data:`~oracledb.DB_TYPE_BFILE`
- No relevant notes
- Cannot be set
- Can fetch a BFILE object and insert that object in a table. Cannot create BFILE objects.
- :ref:`oracledb.LOB <lobobj>`, bytes
* - JSON
- :data:`~oracledb.DB_TYPE_JSON`
- No relevant notes
Expand Down
55 changes: 55 additions & 0 deletions doc/src/user_guide/json_data_type.rst
Original file line number Diff line number Diff line change
Expand Up @@ -380,3 +380,58 @@ for example:
This produces::

[{"deptid":10,"name":"Administration"},{"deptid":20,"name":"Marketing"},{"deptid":30,"name":"Purchasing"},{"deptid":40,"name":"Human Resources"}]

.. _jsondualityviews:

JSON-Relational Duality Views
=============================

Oracle Database 23ai JSON-Relational Duality Views allow data to be stored as
rows in tables to provide the benefits of the relational model and SQL access,
while also allowing access to data as JSON documents for application
simplicity. See the `JSON-Relational Duality Developer's Guide
<https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=JSNVU>`__ for more
information.

For example, if you have tables ``AuthorTab`` and ``BookTab``
containing authors and their books, then a JSON Duality View could be created
in SQL*Plus::

create or replace json relational duality view BookDV as
BookTab @insert @update @delete
{
_id: BookId,
book_title: BookTitle,
author: AuthorTab @insert @update
{
author_id: AuthorId,
author_name: AuthorName
}
}

Applications can choose whether to use relational access to the underlying
tables, or use the duality view.

You can use SQL/JSON to query the view and return JSON. The query uses the
special column ``data``:

.. code-block:: python
sql = """select b.data.book_title, b.data.author.author_name
from BookDV b
where b.data.author.author_id = :1"""
for r in cursor.execute(sql, [1]):
print(r)
Inserting JSON into the view will update the base relational tables:

.. code-block:: python
data = dict(_id=1000, book_title="My New Book",
author=dict(author_id=2000, author_name="John Doe"))
cursor.setinputsizes(oracledb.DB_TYPE_JSON)
cursor.execute("insert into BookDV values (:1)", [data])
See `json_duality.py
<https://github.com/oracle/python-oracledb/tree/main/samples/json_duality.py>`__
for a runnable example.
123 changes: 123 additions & 0 deletions samples/json_duality.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,123 @@
# -----------------------------------------------------------------------------
# Copyright (c) 2024, Oracle and/or its affiliates.
#
# This software is dual-licensed to you under the Universal Permissive License
# (UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl and Apache License
# 2.0 as shown at http://www.apache.org/licenses/LICENSE-2.0. You may choose
# either license.
#
# If you elect to accept the software under the Apache License, Version 2.0,
# the following applies:
#
# Licensed under the Apache License, Version 2.0 (the "License");
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# https://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an "AS IS" BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
# -----------------------------------------------------------------------------

# -----------------------------------------------------------------------------
# json_duality.py
#
# Demonstrates Oracle Database 23ai JSON-Relational Duality Views.
#
# See https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=ADJSN
# -----------------------------------------------------------------------------

import json
import sys

import oracledb
import sample_env

# determine whether to use python-oracledb thin mode or thick mode
if not sample_env.get_is_thin():
oracledb.init_oracle_client(lib_dir=sample_env.get_oracle_client())

connection = oracledb.connect(
user=sample_env.get_main_user(),
password=sample_env.get_main_password(),
dsn=sample_env.get_connect_string(),
)

if not connection.thin:
client_version = oracledb.clientversion()[0]
db_version = int(connection.version.split(".")[0])

# this script only works with Oracle Database 23ai
if db_version < 23:
sys.exit("This example requires Oracle Database 23 or later. ")

with connection.cursor() as cursor:

# Create a JSON-Relational Duality View over the SampleJRDVAuthorTab and
# SampleJRDVBookTab tables
sql = """
create or replace json relational duality view BookDV as
SampleJRDVBookTab @insert @update @delete
{
_id: BookId,
book_title: BookTitle,
author: SampleJRDVAuthorTab @insert @update
{
author_id: AuthorId,
author_name: AuthorName
}
}"""
cursor.execute(sql)

with connection.cursor() as cursor:

# Insert a new book and author into the Duality View and show the resulting
# new records in the relational tables
data = dict(
_id=101,
book_title="Cooking at Home",
author=dict(author_id=201, author_name="Dave Smith"),
)
inssql = "insert into BookDV values (:1)"
if connection.thin or client_version >= 21:
# Take advantage of direct binding
cursor.setinputsizes(oracledb.DB_TYPE_JSON)
cursor.execute(inssql, [data])
else:
# Insert the data as a JSON string
cursor.execute(inssql, [json.dumps(data)])

print("Authors in the relational table:")
for row in cursor.execute(
"select * from SampleJRDVAuthorTab order by AuthorId"
):
print(row)

print("\nBooks in the relational table:")
for row in cursor.execute(
"select * from SampleJRDVBookTab order by BookId"
):
print(row)

# Select from the duality view

with connection.cursor() as cursor:

print("\nDuality view query for an author's books:")
sql = """select b.data.book_title, b.data.author.author_name
from BookDV b
where b.data.author.author_id = :1"""
for r in cursor.execute(sql, [1]):
print(r)

print("\nDuality view query of all records:")
sql = """select data from BookDV"""
if connection.thin or client_version >= 21:
for (j,) in cursor.execute(sql):
print(j)
else:
for (j,) in cursor.execute(sql):
print(json.loads(j.read()))
1 change: 1 addition & 0 deletions samples/sql/create_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -45,6 +45,7 @@ grant
create procedure,
create type,
create sequence,
create view,
select any dictionary,
change notification,
unlimited tablespace
Expand Down
40 changes: 39 additions & 1 deletion samples/sql/create_schema_23.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
/*-----------------------------------------------------------------------------
* Copyright 2023, Oracle and/or its affiliates.
* Copyright 2023, 2024, Oracle and/or its affiliates.
*
* This software is dual-licensed to you under the Universal Permissive License
* (UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl and Apache License
Expand Down Expand Up @@ -37,3 +37,41 @@ create table &main_user..SampleVectorTab (
v8 vector(3, int8)
)
/

create table &main_user..SampleJRDVAuthorTab (
AuthorId number generated by default on null as identity primary key,
AuthorName varchar2(100)
)
/

create table &main_user..SampleJRDVBookTab (
BookId number generated by default on null as identity primary key,
BookTitle varchar2(100),
AuthorId number references &main_user..SampleJRDVAuthorTab (AuthorId)
)
/

insert into &main_user..SampleJRDVAuthorTab values (1, 'Isabel M. Rich')
/
insert into &main_user..SampleJRDVAuthorTab values (2, 'Bobbie Cool')
/
insert into &main_user..SampleJRDVAuthorTab values (3, 'Charlie Shore')
/

insert into &main_user..SampleJRDVBookTab values (1, 'The Mysterious Dog', 1)
/
insert into &main_user..SampleJRDVBookTab values (2, 'The Mysterious Pony', 1)
/
insert into &main_user..SampleJRDVBookTab values (3, 'The Mysterious Tiger', 1)
/
insert into &main_user..SampleJRDVBookTab values (4, 'Self Help for Programmers', 2)
/
insert into &main_user..SampleJRDVBookTab values (5, 'More Self Help for Programmers', 2)
/
insert into &main_user..SampleJRDVBookTab values (6, 'Travel Guide Volume I', 3)
/
insert into &main_user..SampleJRDVBookTab values (7, 'Travel Guide Volume II', 3)
/

commit
/

0 comments on commit 00f5a58

Please sign in to comment.