Skip to content

Commit 00f5a58

Browse files
Update documentation and samples.
1 parent 3eee245 commit 00f5a58

File tree

5 files changed

+225
-4
lines changed

5 files changed

+225
-4
lines changed

doc/src/user_guide/appendix_a.rst

Lines changed: 7 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -187,7 +187,7 @@ see :ref:`driverdiff` and :ref:`compatibility`.
187187
- Yes
188188
- Yes
189189
* - SQL execution (see :ref:`sqlexecution`)
190-
- Yes - bind and fetch all types except BFILE and JSON
190+
- Yes
191191
- Yes
192192
- Yes
193193
* - PL/SQL execution (see :ref:`plsqlexecution`)
@@ -238,6 +238,10 @@ see :ref:`driverdiff` and :ref:`compatibility`.
238238
- No
239239
- Yes
240240
- Yes
241+
* - Oracle Database 23ai JSON-Relational Duality Views (see :ref:`jsondualityviews`)
242+
- Yes
243+
- Yes
244+
- No
241245
* - Continuous Query Notification (CQN) (see :ref:`cqn`)
242246
- No
243247
- Yes
@@ -454,8 +458,8 @@ values.
454458
- :ref:`oracledb.LOB <lobobj>`, bytes, str
455459
* - BFILE
456460
- :data:`~oracledb.DB_TYPE_BFILE`
457-
- No relevant notes
458-
- Cannot be set
461+
- Can fetch a BFILE object and insert that object in a table. Cannot create BFILE objects.
462+
- :ref:`oracledb.LOB <lobobj>`, bytes
459463
* - JSON
460464
- :data:`~oracledb.DB_TYPE_JSON`
461465
- No relevant notes

doc/src/user_guide/json_data_type.rst

Lines changed: 55 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -380,3 +380,58 @@ for example:
380380
This produces::
381381

382382
[{"deptid":10,"name":"Administration"},{"deptid":20,"name":"Marketing"},{"deptid":30,"name":"Purchasing"},{"deptid":40,"name":"Human Resources"}]
383+
384+
.. _jsondualityviews:
385+
386+
JSON-Relational Duality Views
387+
=============================
388+
389+
Oracle Database 23ai JSON-Relational Duality Views allow data to be stored as
390+
rows in tables to provide the benefits of the relational model and SQL access,
391+
while also allowing access to data as JSON documents for application
392+
simplicity. See the `JSON-Relational Duality Developer's Guide
393+
<https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=JSNVU>`__ for more
394+
information.
395+
396+
For example, if you have tables ``AuthorTab`` and ``BookTab``
397+
containing authors and their books, then a JSON Duality View could be created
398+
in SQL*Plus::
399+
400+
create or replace json relational duality view BookDV as
401+
BookTab @insert @update @delete
402+
{
403+
_id: BookId,
404+
book_title: BookTitle,
405+
author: AuthorTab @insert @update
406+
{
407+
author_id: AuthorId,
408+
author_name: AuthorName
409+
}
410+
}
411+
412+
Applications can choose whether to use relational access to the underlying
413+
tables, or use the duality view.
414+
415+
You can use SQL/JSON to query the view and return JSON. The query uses the
416+
special column ``data``:
417+
418+
.. code-block:: python
419+
420+
sql = """select b.data.book_title, b.data.author.author_name
421+
from BookDV b
422+
where b.data.author.author_id = :1"""
423+
for r in cursor.execute(sql, [1]):
424+
print(r)
425+
426+
Inserting JSON into the view will update the base relational tables:
427+
428+
.. code-block:: python
429+
430+
data = dict(_id=1000, book_title="My New Book",
431+
author=dict(author_id=2000, author_name="John Doe"))
432+
cursor.setinputsizes(oracledb.DB_TYPE_JSON)
433+
cursor.execute("insert into BookDV values (:1)", [data])
434+
435+
See `json_duality.py
436+
<https://github.com/oracle/python-oracledb/tree/main/samples/json_duality.py>`__
437+
for a runnable example.

samples/json_duality.py

Lines changed: 123 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,123 @@
1+
# -----------------------------------------------------------------------------
2+
# Copyright (c) 2024, Oracle and/or its affiliates.
3+
#
4+
# This software is dual-licensed to you under the Universal Permissive License
5+
# (UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl and Apache License
6+
# 2.0 as shown at http://www.apache.org/licenses/LICENSE-2.0. You may choose
7+
# either license.
8+
#
9+
# If you elect to accept the software under the Apache License, Version 2.0,
10+
# the following applies:
11+
#
12+
# Licensed under the Apache License, Version 2.0 (the "License");
13+
# you may not use this file except in compliance with the License.
14+
# You may obtain a copy of the License at
15+
#
16+
# https://www.apache.org/licenses/LICENSE-2.0
17+
#
18+
# Unless required by applicable law or agreed to in writing, software
19+
# distributed under the License is distributed on an "AS IS" BASIS,
20+
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
21+
# See the License for the specific language governing permissions and
22+
# limitations under the License.
23+
# -----------------------------------------------------------------------------
24+
25+
# -----------------------------------------------------------------------------
26+
# json_duality.py
27+
#
28+
# Demonstrates Oracle Database 23ai JSON-Relational Duality Views.
29+
#
30+
# See https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=ADJSN
31+
# -----------------------------------------------------------------------------
32+
33+
import json
34+
import sys
35+
36+
import oracledb
37+
import sample_env
38+
39+
# determine whether to use python-oracledb thin mode or thick mode
40+
if not sample_env.get_is_thin():
41+
oracledb.init_oracle_client(lib_dir=sample_env.get_oracle_client())
42+
43+
connection = oracledb.connect(
44+
user=sample_env.get_main_user(),
45+
password=sample_env.get_main_password(),
46+
dsn=sample_env.get_connect_string(),
47+
)
48+
49+
if not connection.thin:
50+
client_version = oracledb.clientversion()[0]
51+
db_version = int(connection.version.split(".")[0])
52+
53+
# this script only works with Oracle Database 23ai
54+
if db_version < 23:
55+
sys.exit("This example requires Oracle Database 23 or later. ")
56+
57+
with connection.cursor() as cursor:
58+
59+
# Create a JSON-Relational Duality View over the SampleJRDVAuthorTab and
60+
# SampleJRDVBookTab tables
61+
sql = """
62+
create or replace json relational duality view BookDV as
63+
SampleJRDVBookTab @insert @update @delete
64+
{
65+
_id: BookId,
66+
book_title: BookTitle,
67+
author: SampleJRDVAuthorTab @insert @update
68+
{
69+
author_id: AuthorId,
70+
author_name: AuthorName
71+
}
72+
}"""
73+
cursor.execute(sql)
74+
75+
with connection.cursor() as cursor:
76+
77+
# Insert a new book and author into the Duality View and show the resulting
78+
# new records in the relational tables
79+
data = dict(
80+
_id=101,
81+
book_title="Cooking at Home",
82+
author=dict(author_id=201, author_name="Dave Smith"),
83+
)
84+
inssql = "insert into BookDV values (:1)"
85+
if connection.thin or client_version >= 21:
86+
# Take advantage of direct binding
87+
cursor.setinputsizes(oracledb.DB_TYPE_JSON)
88+
cursor.execute(inssql, [data])
89+
else:
90+
# Insert the data as a JSON string
91+
cursor.execute(inssql, [json.dumps(data)])
92+
93+
print("Authors in the relational table:")
94+
for row in cursor.execute(
95+
"select * from SampleJRDVAuthorTab order by AuthorId"
96+
):
97+
print(row)
98+
99+
print("\nBooks in the relational table:")
100+
for row in cursor.execute(
101+
"select * from SampleJRDVBookTab order by BookId"
102+
):
103+
print(row)
104+
105+
# Select from the duality view
106+
107+
with connection.cursor() as cursor:
108+
109+
print("\nDuality view query for an author's books:")
110+
sql = """select b.data.book_title, b.data.author.author_name
111+
from BookDV b
112+
where b.data.author.author_id = :1"""
113+
for r in cursor.execute(sql, [1]):
114+
print(r)
115+
116+
print("\nDuality view query of all records:")
117+
sql = """select data from BookDV"""
118+
if connection.thin or client_version >= 21:
119+
for (j,) in cursor.execute(sql):
120+
print(j)
121+
else:
122+
for (j,) in cursor.execute(sql):
123+
print(json.loads(j.read()))

samples/sql/create_schema.sql

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -45,6 +45,7 @@ grant
4545
create procedure,
4646
create type,
4747
create sequence,
48+
create view,
4849
select any dictionary,
4950
change notification,
5051
unlimited tablespace

samples/sql/create_schema_23.sql

Lines changed: 39 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
/*-----------------------------------------------------------------------------
2-
* Copyright 2023, Oracle and/or its affiliates.
2+
* Copyright 2023, 2024, Oracle and/or its affiliates.
33
*
44
* This software is dual-licensed to you under the Universal Permissive License
55
* (UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl and Apache License
@@ -37,3 +37,41 @@ create table &main_user..SampleVectorTab (
3737
v8 vector(3, int8)
3838
)
3939
/
40+
41+
create table &main_user..SampleJRDVAuthorTab (
42+
AuthorId number generated by default on null as identity primary key,
43+
AuthorName varchar2(100)
44+
)
45+
/
46+
47+
create table &main_user..SampleJRDVBookTab (
48+
BookId number generated by default on null as identity primary key,
49+
BookTitle varchar2(100),
50+
AuthorId number references &main_user..SampleJRDVAuthorTab (AuthorId)
51+
)
52+
/
53+
54+
insert into &main_user..SampleJRDVAuthorTab values (1, 'Isabel M. Rich')
55+
/
56+
insert into &main_user..SampleJRDVAuthorTab values (2, 'Bobbie Cool')
57+
/
58+
insert into &main_user..SampleJRDVAuthorTab values (3, 'Charlie Shore')
59+
/
60+
61+
insert into &main_user..SampleJRDVBookTab values (1, 'The Mysterious Dog', 1)
62+
/
63+
insert into &main_user..SampleJRDVBookTab values (2, 'The Mysterious Pony', 1)
64+
/
65+
insert into &main_user..SampleJRDVBookTab values (3, 'The Mysterious Tiger', 1)
66+
/
67+
insert into &main_user..SampleJRDVBookTab values (4, 'Self Help for Programmers', 2)
68+
/
69+
insert into &main_user..SampleJRDVBookTab values (5, 'More Self Help for Programmers', 2)
70+
/
71+
insert into &main_user..SampleJRDVBookTab values (6, 'Travel Guide Volume I', 3)
72+
/
73+
insert into &main_user..SampleJRDVBookTab values (7, 'Travel Guide Volume II', 3)
74+
/
75+
76+
commit
77+
/

0 commit comments

Comments
 (0)