Skip to content

Commit eb1daa4

Browse files
Update documentation and add samples for executemany() with PL/SQL.
1 parent a4258c6 commit eb1daa4

File tree

4 files changed

+513
-8
lines changed

4 files changed

+513
-8
lines changed

doc/src/user_guide/batch_statement.rst

+113-7
Original file line numberDiff line numberDiff line change
@@ -153,12 +153,20 @@ With named bind variables, use named parameters when calling
153153
values (:pid, :pdesc)""", data)
154154
155155
156+
.. _batchplsql:
157+
156158
Batch Execution of PL/SQL
157159
=========================
158160

159-
PL/SQL functions and procedures and anonymous PL/SQL blocks can also be called
160-
using :meth:`~Cursor.executemany()` in order to improve performance. For
161-
example:
161+
Using :meth:`~Cursor.executemany()` can improve performance when PL/SQL
162+
functions, procedures, or anonymous blocks need to be called multiple times.
163+
164+
Runnable examples are in `plsql_batch.py <https://github.com/oracle/python-
165+
oracledb/tree/main/samples/plsql_batch.py>`__.
166+
167+
**IN Binds**
168+
169+
An example using :ref:`bind by position <bindbyposition>` for IN binds is:
162170

163171
.. code-block:: python
164172
@@ -171,12 +179,110 @@ example:
171179
]
172180
cursor.executemany("begin mypkg.create_parent(:1, :2); end;", data)
173181
174-
If ``executemany()`` is used for PL/SQL code that returns OUT binds it will
175-
have the same performance characteristics as repeated calls to ``execute()``.
182+
Note that the ``batcherrors`` parameter of :meth:`~Cursor.executemany()`
183+
(discussed in :ref:`batcherrors`) cannot be used with PL/SQL block execution.
184+
185+
**OUT Binds**
186+
187+
When using OUT binds in PL/SQL, the input data omits entries for the OUT bind
188+
variable placeholders. An example PL/SQL procedure that returns OUT binds is:
189+
190+
.. code-block:: sql
191+
192+
create or replace procedure myproc(p1 in number, p2 out number) as
193+
begin
194+
p2 := p1 * 2;
195+
end;
196+
197+
This can be called in python-oracledb using positional binds like:
198+
199+
.. code-block:: python
200+
201+
data = [
202+
(100,),
203+
(200,),
204+
(300,)
205+
]
206+
207+
outvals = cursor.var(oracledb.DB_TYPE_NUMBER, arraysize=len(data))
208+
cursor.setinputsizes(None, outvals)
209+
210+
cursor.executemany("begin myproc(:1, :2); end;", data)
211+
print(outvals.values)
212+
213+
The output is::
214+
215+
[200, 400, 600]
216+
217+
The equivalent code using named binds is:
218+
219+
.. code-block:: python
220+
221+
data = [
222+
{"p1bv": 100},
223+
{"p1bv": 200},
224+
{"p1bv": 300}
225+
]
226+
227+
outvals = cursor.var(oracledb.DB_TYPE_NUMBER, arraysize=len(data))
228+
cursor.setinputsizes(p1bv=None, p2bv=outvals)
229+
230+
cursor.executemany("begin myproc(:p1bv, :p2bv); end;", data)
231+
print(outvals.values)
232+
233+
Note that in python-oracledb Thick mode, when :meth:`~Cursor.executemany()` is
234+
used for PL/SQL code that returns OUT binds, it will have the same performance
235+
characteristics as repeated calls to :meth:`~Cursor.execute()`.
236+
237+
**IN/OUT Binds**
238+
239+
An example PL/SQL procedure that returns IN/OUT binds is:
240+
241+
.. code-block:: sql
242+
243+
create or replace procedure myproc2 (p1 in number, p2 in out varchar2) as
244+
begin
245+
p2 := p2 || ' ' || p1;
246+
end;
247+
248+
This can be called in python-oracledb using positional binds like:
249+
250+
.. code-block:: python
251+
252+
data = [
253+
(440, 'Gregory'),
254+
(550, 'Haley'),
255+
(660, 'Ian')
256+
]
257+
outvals = cursor.var(oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data))
258+
cursor.setinputsizes(None, outvals)
259+
260+
cursor.executemany("begin myproc2(:1, :2); end;", data)
261+
print(outvals.values)
262+
263+
The ``size`` parameter of :meth:`Cursor.var()` indicates the maximum length of
264+
the string that can be returned.
265+
266+
Output is::
267+
268+
['Gregory 440', 'Haley 550', 'Ian 660']
269+
270+
The equivalent code using named binds is:
271+
272+
.. code-block:: python
273+
274+
data = [
275+
{"p1bv": 440, "p2bv": 'Gregory'},
276+
{"p1bv": 550, "p2bv": 'Haley'},
277+
{"p1bv": 660, "p2bv": 'Ian'}
278+
]
279+
outvals = cursor.var(oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data))
280+
cursor.setinputsizes(p1bv=None, p2bv=outvals)
176281
177-
Note that the ``batcherrors`` parameter (discussed below) cannot be used with
178-
PL/SQL block execution.
282+
cursor.executemany("begin myproc2(:p1bv, :p2bv); end;", data)
283+
print(outvals.values)
179284
285+
.. _batcherrors:
180286

181287
Handling Data Errors
182288
====================

doc/src/user_guide/plsql_execution.rst

+6-1
Original file line numberDiff line numberDiff line change
@@ -4,9 +4,14 @@
44
Executing PL/SQL
55
****************
66

7-
PL/SQL stored procedures, functions and anonymous blocks can be called from
7+
PL/SQL stored procedures, functions, and anonymous blocks can be called from
88
python-oracledb.
99

10+
Examples in this chapter show single invocations using
11+
:meth:`Cursor.callproc()`, :meth:`Cursor.callfunc()`, or
12+
:meth:`Cursor.execute()`. Examples of repeated calls using
13+
:meth:`Cursor.executemany()` are shown in :ref:`batchplsql`.
14+
1015
.. _plsqlproc:
1116

1217
PL/SQL Stored Procedures

samples/plsql_batch.py

+193
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,193 @@
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+
# plsql_batch.py
27+
#
28+
# Demonstrates using executemany() to make repeated calls to a PL/SQL procedure
29+
#
30+
# Note in python-oracledb Thick mode, when cursor.executemany() is used for
31+
# PL/SQL code that returns OUT binds, it will have the same performance
32+
# characteristics as repeated calls to cursor.execute().
33+
# -----------------------------------------------------------------------------
34+
35+
import oracledb
36+
import sample_env
37+
38+
# determine whether to use python-oracledb thin mode or thick mode
39+
if not sample_env.get_is_thin():
40+
oracledb.init_oracle_client(lib_dir=sample_env.get_oracle_client())
41+
42+
connection = oracledb.connect(
43+
user=sample_env.get_main_user(),
44+
password=sample_env.get_main_password(),
45+
dsn=sample_env.get_connect_string(),
46+
params=sample_env.get_connect_params(),
47+
)
48+
49+
# -----------------------------------------------------------------------------
50+
# IN and OUT PL/SQL parameter examples
51+
# Also shows passing in an object
52+
# -----------------------------------------------------------------------------
53+
54+
# Setup
55+
56+
with connection.cursor() as cursor:
57+
stmts = [
58+
"""create or replace type my_varchar_list as table of varchar2(100)""",
59+
"""create or replace procedure myproc
60+
(p in number, names in my_varchar_list, count out number) as
61+
begin
62+
count := p + names.count;
63+
end;""",
64+
]
65+
for s in stmts:
66+
cursor.execute(s)
67+
if cursor.warning:
68+
print(cursor.warning)
69+
print(s)
70+
71+
type_obj = connection.gettype("MY_VARCHAR_LIST")
72+
73+
# Example 1: positional binds
74+
75+
with connection.cursor() as cursor:
76+
77+
obj1 = type_obj.newobject()
78+
obj1.extend(["Alex", "Bobbie"])
79+
obj2 = type_obj.newobject()
80+
obj2.extend(["Charlie", "Dave", "Eric"])
81+
obj3 = type_obj.newobject()
82+
obj3.extend(["Fred", "Georgia", "Helen", "Ian"])
83+
84+
data = [
85+
(1, obj1),
86+
(2, obj2),
87+
(3, obj3),
88+
]
89+
90+
count = cursor.var(oracledb.DB_TYPE_NUMBER, arraysize=len(data))
91+
cursor.setinputsizes(None, type_obj, count)
92+
93+
cursor.executemany("begin myproc(:1, :2, :3); end;", data)
94+
print(count.values) # [3, 5, 7]
95+
96+
# Example 2: named binds
97+
98+
with connection.cursor() as cursor:
99+
100+
obj1 = type_obj.newobject()
101+
obj1.extend(["Alex", "Bobbie"])
102+
obj2 = type_obj.newobject()
103+
obj2.extend(["Charlie", "Dave", "Eric"])
104+
obj3 = type_obj.newobject()
105+
obj3.extend(["Fred", "Georgia", "Helen", "Ian"])
106+
107+
data = [
108+
{"p": 100, "names": obj1},
109+
{"p": 200, "names": obj2},
110+
{"p": 300, "names": obj3},
111+
]
112+
113+
count = cursor.var(oracledb.DB_TYPE_NUMBER, arraysize=len(data))
114+
cursor.setinputsizes(p=None, names=type_obj, count=count)
115+
116+
cursor.executemany("begin myproc(:p, :names, :count); end;", data)
117+
print(count.values) # [102, 203, 304]
118+
119+
# -----------------------------------------------------------------------------
120+
# IN/OUT PL/SQL parameter examples
121+
# -----------------------------------------------------------------------------
122+
123+
# Setup
124+
125+
with connection.cursor() as cursor:
126+
stmt = """create or replace procedure myproc2
127+
(p1 in number, p2 in out varchar2) as
128+
begin
129+
p2 := p2 || ' ' || p1;
130+
end;"""
131+
cursor.execute(stmt)
132+
if cursor.warning:
133+
print(cursor.warning)
134+
print(stmt)
135+
136+
# Example 3: positional binds
137+
138+
with connection.cursor() as cursor:
139+
data = [(440, "Gregory"), (550, "Haley"), (660, "Ian")]
140+
outvals = cursor.var(
141+
oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data)
142+
)
143+
cursor.setinputsizes(None, outvals)
144+
145+
cursor.executemany("begin myproc2(:1, :2); end;", data)
146+
print(outvals.values) # ['Gregory 440', 'Haley 550', 'Ian 660']
147+
148+
# Example 4: positional binds, utilizing setvalue()
149+
150+
with connection.cursor() as cursor:
151+
data = [(777,), (888,), (999,)]
152+
153+
inoutvals = cursor.var(
154+
oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data)
155+
)
156+
inoutvals.setvalue(0, "Roger")
157+
inoutvals.setvalue(1, "Sally")
158+
inoutvals.setvalue(2, "Tom")
159+
cursor.setinputsizes(None, inoutvals)
160+
161+
cursor.executemany("begin myproc2(:1, :2); end;", data)
162+
print(inoutvals.values) # ['Roger 777', 'Sally 888', 'Tom 999']
163+
164+
# Example 5: named binds
165+
166+
with connection.cursor() as cursor:
167+
data = [
168+
{"p1bv": 100, "p2bv": "Alfie"},
169+
{"p1bv": 200, "p2bv": "Brian"},
170+
{"p1bv": 300, "p2bv": "Cooper"},
171+
]
172+
outvals = cursor.var(
173+
oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data)
174+
)
175+
cursor.setinputsizes(p1bv=None, p2bv=outvals)
176+
177+
cursor.executemany("begin myproc2(:p1bv, :p2bv); end;", data)
178+
print(outvals.values) # ['Alfie 100', 'Brian 200', 'Cooper 300']
179+
180+
# Example 6: named binds, utilizing setvalue()
181+
182+
with connection.cursor() as cursor:
183+
inoutvals = cursor.var(
184+
oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data)
185+
)
186+
inoutvals.setvalue(0, "Dean")
187+
inoutvals.setvalue(1, "Elsa")
188+
inoutvals.setvalue(2, "Felix")
189+
data = [{"p1bv": 101}, {"p1bv": 202}, {"p1bv": 303}]
190+
cursor.setinputsizes(p1bv=None, p2bv=inoutvals)
191+
192+
cursor.executemany("begin myproc2(:p1bv, :p2bv); end;", data)
193+
print(inoutvals.values) # ['Dean 101', 'Elsa 202', 'Felix 303']

0 commit comments

Comments
 (0)