Tuesday, August 19, 2014

How to use comma separated string build dynamically and pass to IN clause of select statement


In some cases, we get a comma separated string as output (say from another select statement) that we would need to pass to the IN clause of a select statement.

This article explains how to achieve that using regexp_substr (DB >=10g).

For example, assume a select statement returns the following
'SMITH,ALLEN,WARD,JONES'

Now, we would need to pass this to another select statement as IN clause and get the output.

SQL> select * from emp where ename in ('SMITH,ALLEN,WARD,JONES');

no rows selected

Well, this is not our expected output. We expect the query to return 4 rows.
This can be achieved by splitting the comma separated string to individual strings and pass it to the IN clause.

Oracle provides regexp_substr function, which comes handy for this scenario.
First, we will form a query, that splits this comma separated string and gives the individual strings as rows.

 

SQL> select regexp_substr('SMITH,ALLEN,WARD,JONES','[^,]+', 1, level) from dual
  2  connect by regexp_substr('SMITH,ALLEN,WARD,JONES', '[^,]+', 1, level) is not null;

REGEXP_SUBSTR('SMITH,A
----------------------
SMITH
ALLEN
WARD
JONES

The above query iterates through the comma separated string, searches for the comma (,) and then splits the string by treating the comma as delimiter. It returns the string as a row, whenever it hits a delimiter.

 

We can pass this query to our select statement to get the desired output.

 

SQL> select * from emp where ename in (
  2  select regexp_substr('SMITH,ALLEN,WARD,JONES','[^,]+', 1, level) from dual
  3  connect by regexp_substr('SMITH,ALLEN,WARD,JONES', '[^,]+', 1, level) is not null );

 

EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20

Now, the query returns what we expected.

No comments:

Post a Comment

Note: Only a member of this blog may post a comment.