@@ -13940,44 +13940,40 @@ handled automatically. For SQL calls no temporary LOBs are used.
13940
13940
13941
13941
### <a name="sqlwherein"></a> 22.6 Binding Multiple Values to a SQL `WHERE IN` Clause
13942
13942
13943
- Binding a single JavaScript value into a SQL `WHERE IN` clause is
13944
- easy:
13943
+ Binding a single JavaScript value into a SQL `WHERE IN` clause is easy:
13945
13944
13946
13945
```javascript
13947
- sql = `SELECT last_name FROM employees WHERE first_name IN (:bv)`;
13946
+ sql = `SELECT first_name, last_name FROM employees WHERE first_name IN (:bv)`;
13948
13947
binds = ['Christopher'];
13949
13948
await connection.execute(sql, binds, function(...));
13950
13949
```
13951
13950
13952
- But a common use case for a query `WHERE IN` clause is for multiple
13953
- values, for example when a web user selects multiple check-box options
13954
- and the query should match all chosen values.
13951
+ But a common use case for a SQL `WHERE IN` clause is for multiple values, for
13952
+ example when a web user selects multiple check-box options and the query should
13953
+ match all chosen values.
13955
13954
13956
- Trying to associate multiple data values with a single bind parameter
13957
- will not work. To use a fixed, small number of values in an `WHERE
13958
- IN` bind clause, the SQL query should have individual bind parameters,
13959
- for example:
13955
+ To use a fixed, small number of values in an `WHERE IN` bind clause, the SQL
13956
+ query should have individual bind parameters, for example:
13960
13957
13961
13958
```javascript
13962
- const sql = `SELECT last_name FROM employees WHERE first_name IN (:bv1, :bv2, :bv3, :bv4)`;
13959
+ const sql = `SELECT first_name, last_name FROM employees WHERE first_name IN (:bv1, :bv2, :bv3, :bv4)`;
13963
13960
const binds = ['Alyssa', 'Christopher', 'Hazel', 'Samuel'];
13964
13961
const result = await connection.execute(sql, binds);
13965
13962
```
13966
13963
13967
- If you sometimes execute the query with a smaller number of items, a
13968
- null can be bound for the 'missing' values :
13964
+ If you sometimes execute the query with a smaller number of items, then null
13965
+ can be bound for each 'missing' value :
13969
13966
13970
13967
```javascript
13971
13968
const binds = ['Alyssa', 'Christopher', 'Hazel', null];
13972
13969
```
13973
13970
13974
- When the exact same statement text is re-executed many times
13975
- regardless of the number of user supplied values, you get performance
13976
- and scaling benefits from not having multiple, unique SQL statements
13977
- being run.
13971
+ When the exact same statement text is re-executed many times regardless of the
13972
+ number of user supplied values, this provides performance and scaling benefits
13973
+ from not having multiple, unique SQL statements being run.
13978
13974
13979
- Another solution when the number of data items is only known at
13980
- runtime is to build up an exact SQL string like :
13975
+ If the statement is not going to be re-executed, or the number of values is
13976
+ only going to be known at runtime, then a SQL statement can be built up :
13981
13977
13982
13978
```javascript
13983
13979
const binds = ['Christopher', 'Hazel', 'Samuel'];
@@ -13999,19 +13995,41 @@ and how changeable the number of bind values is, you can end up with lots of
13999
13995
'unique' query strings being executed. You might not get the statement caching
14000
13996
benefits that re-executing a fixed SQL statement would have.
14001
13997
14002
- Another solution for a larger number of values is to construct a SQL
13998
+ A general solution for a larger number of values is to construct a SQL
14003
13999
statement like:
14004
14000
14005
14001
```
14006
- SELECT ... WHERE col IN ( <something that returns a list of rows> )
14002
+ SELECT ... WHERE col IN ( <something that returns a list of values> )
14003
+ ```
14004
+
14005
+ The best way to do the `<something that returns a list of values>` will depend
14006
+ on how the data is initially represented and the number of items. You might
14007
+ look at using CONNECT BY or at using a global temporary table.
14008
+
14009
+ One method is to use an Oracle collection with the ``TABLE()`` clause. For
14010
+ example, if the following type was created::
14011
+
14012
+ ```
14013
+ SQL> CREATE OR REPLACE TYPE name_array AS TABLE OF VARCHAR2(20);
14014
+ 2 /
14015
+ ```
14016
+
14017
+ then the application could do:
14018
+
14019
+ ```javascript
14020
+ const sql = `SELECT first_name, last_name
14021
+ FROM employees
14022
+ WHERE first_name IN (SELECT * FROM TABLE(:bv))`;
14023
+
14024
+ const inlist = ['Christopher', 'Hazel', 'Samuel'];
14025
+
14026
+ const binds = { bv: { type: "NAME_ARRAY", val: inlist } };
14027
+
14028
+ const result = await connection.execute(sql, binds, options);
14007
14029
```
14008
14030
14009
- The easiest way to do the `<something that returns a list of rows>`
14010
- will depend on how the data is initially represented and the number of
14011
- items. You might look at using `CONNECT BY` or nested tables. Or,
14012
- for really large numbers of items, you might prefer to use a global
14013
- temporary table. Some solutions are given in [On Cursors, SQL, and
14014
- Analytics][59] and in [this StackOverflow answer][60].
14031
+ Some general references are [On Cursors, SQL, and Analytics][59] and in [this
14032
+ StackOverflow answer][60].
14015
14033
14016
14034
### <a name="sqlbindlike"></a> 22.7 Binding in a `LIKE` or `REGEXP_LIKE` Clause
14017
14035
@@ -17769,7 +17787,7 @@ can be asked at [AskTom][158].
17769
17787
[54]: https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-1EF347AE-7FDA-4B41-AFE0-DD5A49E8B370
17770
17788
[57]: https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=ADJSN
17771
17789
[58]: https://github.com/oracle/node-oracledb/tree/main/examples/plsqlarray.js
17772
- [59]: https://blogs.oracle.com/oraclemagazine/on-cursors-sql-and-analytics
17790
+ [59]: https://blogs.oracle.com/oraclemagazine/post/ on-cursors-sql-and-analytics
17773
17791
[60]: https://stackoverflow.com/a/43330282/4799035
17774
17792
[61]: https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-4947CAE8-1F00-4897-BB2B-7F921E495175
17775
17793
[62]: https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-56AEF38E-9400-427B-A818-EDEC145F7ACD
0 commit comments