Codebase list python-cx-oracle / aecf006
Further tweaks to documentation and release notes in preparation for release of 8.0.1. Anthony Tuininga 3 years ago
2 changed file(s) with 100 addition(s) and 93 deletion(s). Raw diff Collapse all Expand all
44 cx_Oracle Release Notes
55 =======================
66
7 Version 8.0.1 (TBD)
8 -------------------
7 Version 8.0.1 (August 2020)
8 ---------------------------
99
1010 #) Updated embedded ODPI-C to `version 4.0.2
1111 <https://oracle.github.io/odpi/doc/releasenotes.html#
12 version-4-0-2-TBD>`__. This includes the fix for
12 version-4-0-2-august-31-2020>`__. This includes the fix for binding and
13 fetching numbers with 39 or 40 decimal digits
1314 (`issue 459 <https://github.com/oracle/python-cx_Oracle/issues/459>`__).
14 #) Added metadata (and an exception) specifying that Python 3.5 and higher is
15 required in order to allow pip (and the exception message) to direct those
16 using Python 2 to use version 7.3 instead.
15 #) Added build metadata specifying that Python 3.5 and higher is required in
16 order to avoid downloading and failing to install with Python 2. The
17 exception message when running ``setup.py`` directly was updated to inform
18 those using Python 2 to use version 7.3 instead.
1719 #) Documentation improvements.
1820
1921
9090 performance and scalability. An overhead of prefetching is the need for an
9191 additional data copy from Oracle Client's prefetch buffers.
9292
93 To tune queries that return an unknown number of rows, estimate the number of
94 rows returned and start with an appropriate :attr:`Cursor.arraysize` value. The
95 default is 100. Then set :attr:`Cursor.prefetchrows` to the ``arraysize``
96 value. Do not make the sizes unnecessarily large. Keep ``arraysize`` as big,
97 or bigger than, ``prefetchrows``. Adjust the values as needed for performance,
98 memory and round-trip usage. An example is:
99
100 .. code-block:: python
101
102 cur = connection.cursor()
103
104 cur.prefetchrows = 1000
105 cur.arraysize = 1000
106
107 for row in cur.execute("SELECT * FROM very_big_table"):
108 print(row)
109
110 For a large quantity of rows or very "wide" rows on fast networks you may prefer
111 to leave ``prefetchrows`` at its default value of 2. The documentation in
112 :ref:`roundtrips` shows how to measure round-trips.
113
114 If you are fetching a fixed number of rows, start your tuning by setting
115 ``arraysize`` to the number of expected rows, and set ``prefetchrows`` to one
116 greater than this value. (Adding one removes the need for a round-trip to check
117 for end-of-fetch). For example, if you are querying 20 rows, perhaps to
118 :ref:`display a page <rowlimit>` of data, set ``prefetchrows`` to 21 and
119 ``arraysize`` to 20:
120
121 .. code-block:: python
122
123 cur = connection.cursor()
124
125 cur.prefetchrows = 21
126 cur.arraysize = 20
127
128 for row in cur.execute("""
129 SELECT last_name
130 FROM employees
131 ORDER BY last_name
132 OFFSET 0 ROWS FETCH NEXT 20 ROWS ONLY"""):
133 print(row)
134
135 This will return all rows for the query in one round-trip.
136
137 If you know that a query returns just one row then set :attr:`Cursor.arraysize`
138 to 1 to minimize memory usage. The default prefetch value of 2 allows minimal
139 round-trips for single-row queries:
140
141 .. code-block:: python
142
143 cur = connection.cursor()
144 cur.arraysize = 1
145 cur.execute("select * from MyTable where id = 1"):
146 row = cur.fetchone()
147 print(row)
93 Choosing values for ``arraysize`` and ``prefetchrows``
94 ++++++++++++++++++++++++++++++++++++++++++++++++++++++
14895
14996 The best :attr:`Cursor.arraysize` and :attr:`Cursor.prefetchrows` values can be
15097 found by experimenting with your application under the expected load of normal
15299 prefetch buffers when fetching a large quantity of rows or very "wide" rows may
153100 outweigh the cost of a round-trip for a single cx_Oracle user on a fast network.
154101 However under production application load, the reduction of round-trips may help
155 performance and overall system scalability.
102 performance and overall system scalability. The documentation in
103 :ref:`round-trips <roundtrips>` shows how to measure round-trips.
104
105 Here are some suggestions for the starting point to begin your tuning:
106
107 * To tune queries that return an unknown number of rows, estimate the number of
108 rows returned and start with an appropriate :attr:`Cursor.arraysize` value.
109 The default is 100. Then set :attr:`Cursor.prefetchrows` to the ``arraysize``
110 value. Do not make the sizes unnecessarily large. For example:
111
112 .. code-block:: python
113
114 cur = connection.cursor()
115
116 cur.prefetchrows = 1000
117 cur.arraysize = 1000
118
119 for row in cur.execute("SELECT * FROM very_big_table"):
120 print(row)
121
122 Adjust the values as needed for performance, memory and round-trip usage. For
123 a large quantity of rows or very "wide" rows on fast networks you may prefer
124 to leave ``prefetchrows`` at its default value of 2. Keep ``arraysize`` as
125 big, or bigger than, ``prefetchrows``.
126
127 * If you are fetching a fixed number of rows, start your tuning by setting
128 ``arraysize`` to the number of expected rows, and set ``prefetchrows`` to one
129 greater than this value. (Adding one removes the need for a round-trip to check
130 for end-of-fetch). For example, if you are querying 20 rows, perhaps to
131 :ref:`display a page <rowlimit>` of data, set ``prefetchrows`` to 21 and
132 ``arraysize`` to 20:
133
134 .. code-block:: python
135
136 cur = connection.cursor()
137
138 cur.prefetchrows = 21
139 cur.arraysize = 20
140
141 for row in cur.execute("""
142 SELECT last_name
143 FROM employees
144 ORDER BY last_name
145 OFFSET 0 ROWS FETCH NEXT 20 ROWS ONLY"""):
146 print(row)
147
148 This will return all rows for the query in one round-trip.
149
150 * If you know that a query returns just one row then set :attr:`Cursor.arraysize`
151 to 1 to minimize memory usage. The default prefetch value of 2 allows minimal
152 round-trips for single-row queries:
153
154 .. code-block:: python
155
156 cur = connection.cursor()
157 cur.arraysize = 1
158 cur.execute("select * from MyTable where id = 1"):
159 row = cur.fetchone()
160 print(row)
161
162 In cx_Oracle, the ``arraysize`` and ``prefetchrows`` values are only examined
163 when a statement is executed the first time. To change the values, create a new
164 cursor. For example, to change ``arraysize`` for a repeated statement:
165
166 .. code-block:: python
167
168 array_sizes = (10, 100, 1000)
169 for size in array_sizes:
170 cursor = connection.cursor()
171 cursor.arraysize = size
172 start = time.time()
173 cursor.execute(sql).fetchall()
174 elapsed = time.time() - start
175 print("Time for", size, elapsed, "seconds")
176
177 There are two cases that will benefit from setting :attr:`Cursor.prefetchrows`
178 to 0:
179
180 * When passing REF CURSORS into PL/SQL packages. Setting ``prefetchrows`` to 0
181 can stop rows being prematurely (and silently) fetched into cx_Oracle's
182 internal buffers, making them unavailable to the PL/SQL code that receives the
183 REF CURSOR.
184
185 * When querying a PL/SQL function that uses PIPE ROW to emit rows at
186 intermittent intervals. By default, several rows needs to be emitted by the
187 function before cx_Oracle can return them to the application. Setting
188 ``prefetchrows`` to 0 helps give a consistent flow of data to the application.
156189
157190 Prefetching can also be enabled in an external :ref:`oraaccess.xml
158191 <optclientfiles>` file, which may be useful for tuning an application when
177210 break
178211 targetCursor.executemany("insert into MyTable values (:1, :2)", rows)
179212 targetConnection.commit()
180
181 In cx_Oracle, the ``arraysize`` and ``prefetchrows`` values are only examined
182 when a statement is executed the first time. To change the values, create a new
183 cursor. For example, to change ``arraysize`` for a repeated statement:
184
185 .. code-block:: python
186
187 array_sizes = (10, 100, 1000)
188 for size in array_sizes:
189 cursor = connection.cursor()
190 cursor.arraysize = size
191 start = time.time()
192 cursor.execute(sql).fetchall()
193 elapsed = time.time() - start
194 print("Time for", size, elapsed, "seconds")
195
196 There are two cases that will benefit from setting :attr:`Cursor.prefetchrows`
197 to 0:
198
199 * When passing REF CURSORS into PL/SQL packages. Setting ``prefetchrows`` to 0
200 can stop rows being prematurely (and silently) fetched into cx_Oracle's
201 internal buffers, making them unavailable to the PL/SQL code that receives the
202 REF CURSOR.
203
204 * When querying a PL/SQL function that uses PIPE ROW to emit rows at
205 intermittent intervals. By default, several rows needs to be emitted by the
206 function before cx_Oracle can return them to the application. Setting
207 ``prefetchrows`` to 0 helps give a consistent flow of data to the application.
208213
209214 .. _roundtrips:
210215
304309
305310 .. _clientresultcache:
306311
307 Client Result Cache
308 ===================
312 Client Result Caching
313 =====================
309314
310315 cx_Oracle applications can use Oracle Database's `Client Result Cache
311316 <https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-35CB2592-7588-4C2D-9075-6F639F25425E>`__.
331336 SQL> STARTUP FORCE
332337
333338 CRC can alternatively be configured in an :ref:`oraaccess.xml <optclientfiles>`
334 or :ref:`sqlnet.ora <optnetfiles>` file on the Node.js host, see `Client
339 or :ref:`sqlnet.ora <optnetfiles>` file on the Python host, see `Client
335340 Configuration Parameters
336341 <https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-E63D75A1-FCAA-4A54-A3D2-B068442CE766>`__.
337342