When fetching REF cursors, only the cursor's arraysize attribute is

considered. Previously, the cursor's prefetchrows attribute was also
considered, but in differing ways between thin and thick modes.
This commit is contained in:
Anthony Tuininga 2023-06-15 15:28:59 -06:00
parent 132e6c5222
commit cafbf3761d
7 changed files with 52 additions and 33 deletions

View File

@ -23,6 +23,9 @@ Thin Mode Changes
#) Fixed bug when executing PL/SQL with a large number of binds.
#) Eliminated unneeded round trip when using token authentication to connect
to the database.
#) Adjusted fetching of REF cursors so that the cursor's arraysize attribute
is consistently taken into account before each internal fetch is performed.
This ensures that the number of round trips can be easily determined.
Thick Mode Changes
++++++++++++++++++
@ -34,6 +37,10 @@ Thick Mode Changes
Common Changes
++++++++++++++
#) When fetching REF cursors, only the cursor's arraysize attribute is
considered. Previously, the cursor's prefetchrows attribute was also
considered, but in differing ways between thin and thick modes.
oracledb 1.3.1 (April 2023)
---------------------------

View File

@ -245,11 +245,10 @@ Avoiding Premature Prefetching
There are two cases that will benefit from setting ``prefetchrows`` to zero:
* When passing REF CURSORS into PL/SQL packages. Setting ``prefetchrows`` to 0
can stop rows being prematurely (and silently) fetched into the
python-oracledb or Oracle Client (in python-oracledb Thick mode) internal
buffer, making those rows unavailable to the PL/SQL code that receives the
REF CURSOR.
* When passing REF CURSORS *into* PL/SQL packages. Setting ``prefetchrows`` to
0 can stop rows being prematurely (and silently) fetched into the
python-oracledb internal buffer, making those rows unavailable to the PL/SQL
code that receives the REF CURSOR.
* When querying a PL/SQL function that uses PIPE ROW to emit rows at
intermittent intervals. By default, several rows needs to be emitted by the
@ -259,28 +258,34 @@ There are two cases that will benefit from setting ``prefetchrows`` to zero:
Tuning Fetching from REF CURSORS
--------------------------------
In python-oracledb, fetching data from REF CURSORS can be tuned by setting the
values of ``arraysize`` and ``prefetchrows``. The ``prefetchrows`` value must
be set before calling the PL/SQL procedure because the REF CURSOR is executed
on the server.
The internal buffering and performance of fetching data from REF CURSORS can be
tuned by setting the value of ``arraysize`` before rows are fetched from the
cursor. The ``prefetchrows`` value is ignored when fetching *from* REF CURSORS.
For example:
.. code-block:: python
# Set the arraysize and prefetch rows of the REF cursor
ref_cursor = connection.cursor()
ref_cursor.prefetchrows = 1000
ref_cursor.arraysize = 1000
# Perform the tuned fetch
sum_rows = 0
cursor.callproc("myrefcursorproc", [ref_cursor])
ref_cursor.arraysize = 1000
print("Sum of IntCol for", num_rows, "rows:")
for row in ref_cursor:
sum_rows += row[0]
print(sum_rows)
The ``arraysize`` value can also be set before calling the procedure:
.. code-block:: python
ref_cursor = connection.cursor()
ref_cursor.arraysize = 1000
cursor.callproc("myrefcursorproc", [ref_cursor])
for row in ref_cursor:
. . .
.. _roundtrips:
Also see `Avoiding Premature Prefetching`_.

View File

@ -199,9 +199,6 @@ cdef class ThickVarImpl(BaseVarImpl):
if dpiStmt_addRef(data.value.asStmt) < 0:
_raise_from_odpi()
cursor_impl._handle = data.value.asStmt
if dpiStmt_setPrefetchRows(cursor_impl._handle,
cursor_impl.prefetchrows) < 0:
_raise_from_odpi()
cursor_impl._fixup_ref_cursor = True
cursor.statement = None

View File

@ -104,10 +104,10 @@ cdef class ThinCursorImpl(BaseCursorImpl):
cdef MessageWithData message
if self._statement._requires_full_execute:
message = self._create_message(ExecuteMessage, cursor)
message.num_execs = self._fetch_array_size
else:
message = self._create_message(FetchMessage, cursor)
self._conn_impl._protocol._process_single_message(message)
self._statement._requires_full_execute = False
cdef BaseConnImpl _get_conn_impl(self):
"""

View File

@ -352,7 +352,6 @@ cdef class MessageWithData(Message):
cursor = self.cursor.connection.cursor()
cursor_impl = cursor._impl
cursor_impl._statement = Statement()
cursor_impl._fetch_array_size = cursor.arraysize + cursor.prefetchrows
cursor_impl._more_rows_to_fetch = True
cursor_impl._statement._is_query = True
cursor_impl._statement._requires_full_execute = True
@ -1856,13 +1855,13 @@ cdef class ExecuteMessage(MessageWithData):
if self.parse_only:
options |= TNS_EXEC_OPTION_DESCRIBE
else:
if self.cursor_impl.prefetchrows > 0:
options |= TNS_EXEC_OPTION_FETCH
if stmt._cursor_id == 0 or stmt._requires_define:
num_iters = self.cursor_impl.prefetchrows
self.cursor_impl._fetch_array_size = num_iters
else:
num_iters = self.cursor_impl._fetch_array_size
num_iters = self.cursor_impl.arraysize
self.cursor_impl._fetch_array_size = num_iters
if num_iters > 0:
options |= TNS_EXEC_OPTION_FETCH
if not stmt._is_plsql and not self.parse_only:
options |= TNS_EXEC_OPTION_NOT_PLSQL
elif stmt._is_plsql and num_params > 0:

View File

@ -138,8 +138,8 @@ class TestCase(test_env.BaseTestCase):
rows = ref_cursor.fetchall()
self.assertEqual(rows, expected_value)
def test_1306_refcursor_prefetchrows(self):
"1306 - test prefetch rows and arraysize using a refcursor"
def test_1306_refcursor_round_trips(self):
"1306 - test round trips using a REF cursor"
self.setup_round_trip_checker()
# simple DDL only requires a single round trip
@ -155,14 +155,23 @@ class TestCase(test_env.BaseTestCase):
cursor.executemany(sql, data)
self.assertRoundTrips(1)
# create refcursor and execute stored procedure
# create REF cursor and execute stored procedure
# (array size set before procedure is called)
with self.connection.cursor() as cursor:
refcursor = self.connection.cursor()
refcursor.prefetchrows = 150
refcursor.arraysize = 50
refcursor.arraysize = 150
cursor.callproc("myrefcursorproc", [refcursor])
refcursor.fetchall()
self.assertRoundTrips(4)
self.assertRoundTrips(5)
# create REF cursor and execute stored procedure
# (array size set after procedure is called)
with self.connection.cursor() as cursor:
refcursor = self.connection.cursor()
cursor.callproc("myrefcursorproc", [refcursor])
refcursor.arraysize = 145
refcursor.fetchall()
self.assertRoundTrips(6)
def test_1307_refcursor_execute_different_sql(self):
"1307 - test executing different SQL after getting a REF cursor"

View File

@ -346,13 +346,15 @@ class TestCase(test_env.BaseTestCase):
num_rows = 590
with self.connection.cursor() as cursor:
cursor.execute("truncate table TestTempTable")
self.assertRoundTrips(1)
sql = "insert into TestTempTable (IntCol) values (:1)"
data = [(n + 1,) for n in range(num_rows)]
cursor.executemany(sql, data)
cursor.prefetchrows = 300
cursor.arraysize = 300
self.assertRoundTrips(1)
cursor.prefetchrows = 30
cursor.arraysize = 100
cursor.execute("select IntCol from TestTempTable").fetchall()
self.assertRoundTrips(4)
self.assertRoundTrips(7)
def test_4324_bind_names_with_single_line_comments(self):
"4324 - test bindnames() with single line comments"