Skip to content

Commit ae687ce

Browse files
Improve documentation for WHERE IN clauses.
1 parent 2d33fec commit ae687ce

File tree

1 file changed

+44
-18
lines changed

1 file changed

+44
-18
lines changed

doc/src/user_guide/bind.rst

+44-18
Original file line numberDiff line numberDiff line change
@@ -681,8 +681,9 @@ objects seamlessly:
681681
Binding Multiple Values to a SQL WHERE IN Clause
682682
================================================
683683

684-
To use an IN clause with multiple values in a WHERE clause, you must define and
685-
bind multiple values. You cannot bind an array of values. For example:
684+
To use a SQL IN clause with multiple values, use one bind variable per
685+
value. You cannot directly bind a Python list or dictionary to a single bind
686+
variable. For example, to use two values in an IN clause:
686687

687688
.. code-block:: python
688689
@@ -694,18 +695,18 @@ bind multiple values. You cannot bind an array of values. For example:
694695
for row in cursor:
695696
print(row)
696697
697-
This will produce the following output::
698+
This gives the output::
698699

699700
(159, 'Lindsey', 'Smith')
700701
(171, 'William', 'Smith')
701702
(176, 'Jonathon', 'Taylor')
702703
(180, 'Winston', 'Taylor')
703704

704-
If this sort of query is executed multiple times with differing numbers of
705-
values, a bind variable should be included for each possible value up to the
706-
maximum number of values that can be provided. Missing values can be bound with
707-
the value ``None``. For example, if the query above is used for up to 5 values,
708-
the code should be adjusted as follows:
705+
If the query is executed multiple times with differing numbers of values, a
706+
bind variable should be included for each possible value. When the statement is
707+
executed but the maximum number of values has not been supplied, the value
708+
``None`` can be bound for missing values. For example, if the query above is
709+
used for up to 5 values, the code would be:
709710

710711
.. code-block:: python
711712
@@ -717,10 +718,14 @@ the code should be adjusted as follows:
717718
for row in cursor:
718719
print(row)
719720
720-
This will produce the same output as the original example.
721+
This will produce the same output as the original example. Reusing the same SQL
722+
statement like this for a variable number of values, instead of constructing a
723+
unique statement per set of values, allows best reuse of Oracle Database
724+
resources.
721725

722-
If the number of values is only going to be known at runtime, then a SQL
723-
statement can be built up as follows:
726+
However, if the statement is not going to be re-executed, or the number of
727+
values is only going to be known at runtime, then a SQL statement can be built
728+
up as follows:
724729

725730
.. code-block:: python
726731
@@ -732,16 +737,37 @@ statement can be built up as follows:
732737
for row in cursor:
733738
print(row)
734739
735-
Another solution for a larger number of values is to construct a SQL
740+
A general solution for a larger number of values is to construct a SQL
736741
statement like::
737742

738-
SELECT ... WHERE col IN ( <something that returns a list of rows> )
743+
SELECT ... WHERE col IN ( <something that returns a list of values> )
744+
745+
The best way to do the '<something that returns a list of values>' will depend
746+
on how the data is initially represented and the number of items. You might
747+
look at using CONNECT BY or at using a global temporary table.
748+
749+
One method is to use an Oracle collection with the ``TABLE()`` clause. For
750+
example, if the following type was created::
751+
752+
SQL> CREATE OR REPLACE TYPE name_array AS TABLE OF VARCHAR2(25);
753+
2 /
754+
755+
then the application could do:
756+
757+
.. code-block:: python
758+
759+
type_obj = connection.gettype("NAME_ARRAY")
760+
obj = type_obj.newobject()
761+
obj.extend(["Smith", "Taylor"])
762+
cursor.execute("""select employee_id, first_name, last_name
763+
from employees
764+
where last_name in (select * from table(:1))""",
765+
[obj])
766+
for row in cursor:
767+
print(row)
739768
740-
The easiest way to do the '<something that returns a list of rows>'
741-
will depend on how the data is initially represented and the number of
742-
items. You might look at using CONNECT BY or nested tables. Or,
743-
for really large numbers of items, you might prefer to use a global
744-
temporary table.
769+
For efficiency, retain the return value of ``gettype()`` for reuse instead of
770+
making repeated calls to get the type information.
745771

746772
Binding Column and Table Names
747773
==============================

0 commit comments

Comments
 (0)