Skip to Main Content

Breadcrumb

May 4th

Question and Answer

Connor McDonald

Thanks for the question, Thomas.

Asked: May 02, 2000 - 3:57 pm UTC

Last updated: October 21, 2020 - 1:21 am UTC

Version: 8.1.5

Viewed 100K+ times! This question is

You Asked

I have a simple stored procedure, that I would like to have a passed in string(varchar2) for used in select from where col1 in (var1) in a stored procedure. I've tried everything but doesn't work. Followed is my proc.

Thanks

CREATE OR REPLACE PROCEDURE WSREVSECT_5

pSectNos varchar2,
pRetCode OUT varchar2
)
AS
nCount number;

BEGIN

SELECT count(fksrev) into nCount
FROM SREVSECT
WHERE sectno IN (pSectNos ) /* as in 'abc', 'xyz', '012' */
;
pRetCode:=to_char(ncount);

End;



and Tom said...

it works -- the above is the same as

where sectno = pSectNos

though, not what you want. You want it to be:

where sectno in ( 'abc', 'xyz', '012' )

NOT:

where sectno in ( '''abc'', ''xyz'', ''012''' )

which is effectively is (else you could never search on a string with commas and quotes and so on -- it is doing the only logical thing right now).

You can do this:

SQL> create or replace type myTableType as table
of varchar2 (255);
2 /

Type created.

ops$tkyte@dev8i> create or replace
function in_list( p_string in varchar2 ) return myTableType
2 as
3 l_string long default p_string || ',';
4 l_data myTableType := myTableType();
5 n number;
6 begin
7 loop
8 exit when l_string is null;
9 n := instr( l_string, ',' );
10 l_data.extend;
11 l_data(l_data.count) :=
ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
12 l_string := substr( l_string, n+1 );
13 end loop;
14
15 return l_data;
16 end;
17 /

Function created.

ops$tkyte@dev8i> select *
2 from THE
( select cast( in_list('abc, xyz, 012') as
mytableType ) from dual ) a
3 /

COLUMN_VALUE
------------------------
abc
xyz
012

ops$tkyte@dev8i> select * from all_users where username in
2 ( select *
3 from THE ( select cast( in_list('OPS$TKYTE, SYS, SYSTEM')
as mytableType ) from dual ) )
4 /

USERNAME USER_ID CREATED
------------------------------ ---------- ---------
OPS$TKYTE 23761 02-MAY-00
SYS 0 20-APR-99
SYSTEM 5 20-APR-99



Rating

  (259 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Good ideas; nice to see all the parts

Kristy, April 05, 2001 - 11:06 am UTC


Beware of the performance hit

Andy Barker, November 01, 2001 - 11:43 am UTC

Nice idea but the execution path can be made much worse such that the execution time becomes much slower than if Oracle has to hard parse a new query each time. You can no longer use the elements in the list as keys for index lookups, which may mean full table scans with hash/merge joins rather than nested loop index joins.

Tom Kyte
November 01, 2001 - 4:06 pm UTC

On the flip side of life - the execution path could become much better (look on the bright side).

You know, there is an "evil" side and a "good" side to everything.  Here, you might have to tune your query in order to make use of bind variables.   I can assure you 100% that if you do not use bind variables and just glue the values in -- your system will

o run slower.
o not scale.
o perhaps not run at all.

It can run just as well (or better) then an explicit inlist.  I have to make the assumption sometimes that people can analyze performance, figure somethings out.  Hopefully they would recognize if the plan wasn't what they wanted and would know a thing or two to correct that.  For example:

ops$tkyte@ORA717DEV.US.ORACLE.COM> variable x varchar2(255)
ops$tkyte@ORA717DEV.US.ORACLE.COM> define x="1,2,3,4,5"
ops$tkyte@ORA717DEV.US.ORACLE.COM> exec :x := '&X'
PL/SQL procedure successfully completed.

ops$tkyte@ORA717DEV.US.ORACLE.COM> /*
DOC>drop table t;
DOC>create table t as select * from all_objects;
DOC>alter table t add constraint t_pk primary key(object_id);
DOC>analyze table t compute statistics for table for all indexes for all indexed columns;
DOC>*/

ops$tkyte@ORA717DEV.US.ORACLE.COM> set autotrace traceonly

ops$tkyte@ORA717DEV.US.ORACLE.COM> select * from t where object_id in ( &X );
old   1: select * from t where object_id in ( &X )
new   1: select * from t where object_id in ( 1,2,3,4,5 )


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=7 Card=5 Bytes=485)
   1    0   INLIST ITERATOR
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'T' (Cost=7 Card=5 Bytes=485)
   3    2       INDEX (RANGE SCAN) OF 'T_PK' (UNIQUE) (Cost=2 Card=5)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         14  consistent gets
          0  physical reads
          0  redo size
       1269  bytes sent via SQL*Net to client
        430  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          3  rows processed

ops$tkyte@ORA717DEV.US.ORACLE.COM> select /*+ first_rows */ * from t where object_id in (
  2  select *
  3    from TABLE(cast( in_list( :x ) as myTableType) )
  4  )
  5  /


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=HINT: FIRST_ROWS (Cost=8182 Card=8168 Bytes=1845968)
   1    0   NESTED LOOPS (Cost=8182 Card=8168 Bytes=1845968)
   2    1     VIEW OF 'VW_NSO_1' (Cost=14 Card=8168 Bytes=1053672)
   3    2       SORT (UNIQUE) (Cost=14 Card=8168)
   4    3         COLLECTION ITERATOR (PICKLER FETCH)
   5    1     TABLE ACCESS (BY INDEX ROWID) OF 'T' (Cost=1 Card=17083 Bytes=1657051)
   6    5       INDEX (UNIQUE SCAN) OF 'T_PK' (UNIQUE)




Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         19  consistent gets
          0  physical reads
          0  redo size
       1269  bytes sent via SQL*Net to client
        430  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          4  sorts (memory)
          0  sorts (disk)
          3  rows processed

Not significantly different in my case. 

Execute Immediate

Jan, November 12, 2001 - 8:16 am UTC

I created this FUNCTION:

CREATE OR REPLACE FUNCTION Get_Count (p_string VARCHAR2)
RETURN INTEGER
IS

v_count INTEGER;

BEGIN

IF p_string IS NOT NULL THEN
EXECUTE IMMEDIATE
'SELECT COUNT(1) FROM POLICY_STATUS_TYPES
WHERE STATUS_CODE IN ('''||p_string||''')'
INTO v_count;
ELSE
EXECUTE IMMEDIATE
'SELECT COUNT(1) FROM POLICY_STATUS_TYPES'
INTO v_count;
END IF;

RETURN v_count;

END Get_Count;


If I want to use this function with 0..x parameters - e.g. WHERE IN ('AA','BB'), I just call it like this :

DECLARE

v_string VARCHAR2(200):='AA'',''BB';
v_count INTEGER;
BEGIN

v_count:=Get_Count(v_string);

dbms_output.put_line(v_count);
END;


Jan

Tom Kyte
November 12, 2001 - 9:49 am UTC

And that function does not use bind variables which I consider to be the cardinal sin to end all sins in Oracle programming.

Additionally, it uses dynamic sql in PLSQL when it doesn't need to -- another performance hit (no cursor caching, more parses per session, less scalable, less performant).

At the VERY LEAST, in 816 and up, code this like this:

ops$tkyte@ORA717DEV.US.ORACLE.COM> create or replace function foo( p_string in varchar2 ) return number
  2  as
  3          l_cnt number;
  4  begin
  5          execute immediate
  6          'alter session set cursor_sharing = force';
  7  
  8          execute immediate
  9          'select count(*) from dual where dummy in ( ' || p_string || 
                ')' into l_cnt;
 10  
 11          execute immediate
 12          'alter session set cursor_sharing = exact';
 13  
 14          return l_cnt;
 15  end;
 16  /

Function created.


Cursor sharing is a "crutch" that can help you out (it is NOT the solution to bind variable problems -- it can help lighten the load but is not the answer)

Using that, we'll find:

ops$tkyte@ORA717DEV.US.ORACLE.COM> exec dbms_output.put_line( foo( ' ''A'', ''B'' ' ) );
0

PL/SQL procedure successfully completed.

ops$tkyte@ORA717DEV.US.ORACLE.COM> exec dbms_output.put_line( foo( ' ''A'', ''B'', ''C'' ' ) );
0

PL/SQL procedure successfully completed.

ops$tkyte@ORA717DEV.US.ORACLE.COM> 
ops$tkyte@ORA717DEV.US.ORACLE.COM> select sql_text from v$sql where upper(sql_text) like 'SELECT COUNT(*) FROM DUAL%';

SQL_TEXT
-----------------------------------------------------------------------------------------------------------------------------------
select count(*) from dual where dummy in (  :"SYS_B_0", :"SYS_B_1", :"SYS_B_2" )
select count(*) from dual where dummy in (  :"SYS_B_0", :"SYS_B_1" )

We get as many copies of the query as we have elements in the inlist -- we won't get a QUERY per inlist -- but rather a query plan for queries with 1 element, 2 elements, 3 elements, 4 elements and so on.

This works in 816 and up ONLY. 

How can I do a variable "in list

Niloufar, December 06, 2001 - 4:29 pm UTC

I was working on a similar procedure where I needed to be able to have a "WHERE column_name IN (my_listof_strings)" clause. I tried your solution which works fine in SQLPLUS but when I try to do the same thing in a PL/SQL procedure, I get the following error in the "select ... from dual" statement:

PLS-00513: PL/SQL function called from SQL must return
value of legal SQL type

Which makes sense as you also have mentioned in another article we can't use PLSQL types in SQL. But then, how do I implement this in PL/SQL?

Thanks for your help.

Tom Kyte
December 07, 2001 - 9:01 am UTC

It works "as is" in PLSQL -- as long as you created the TYPE as a SQL type and didn't try to hide it inside of a spec or body.  

ops$tkyte@ORA817DEV.US.ORACLE.COM> create or replace type myTableType as table
  2  of varchar2(4000)
  3  /

Type created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> create or replace
  2  function in_list( p_string in varchar2 ) return myTableType
  3  as
  4      l_string        long default p_string || ',';
  5      l_data          myTableType := myTableType();
  6      n               number;
  7  begin
  8    loop
  9        exit when l_string is null;
 10        n := instr( l_string, ',' );
 11        l_data.extend;
 12        l_data(l_data.count) :=
 13              ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
 14        l_string := substr( l_string, n+1 );
 15   end loop;
 16  
 17   return l_data;
 18  end;
 19  /

Function created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> select *
  2    from THE
  3       ( select cast( in_list('abc, xyz, 012') as
  4                             mytableType ) from dual ) a
  5  /

COLUMN_VALUE
-----------------------------------------------------------------------------------------------------------------------------------
abc
xyz
012

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> select * from all_users where username in
  2    ( select *
  3      from THE ( select cast( in_list('OPS$TKYTE, SYS, SYSTEM')
  4                        as mytableType ) from dual ) )
  5  /

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
OPS$TKYTE                              63 05-NOV-01
SYS                                     0 28-AUG-01
SYSTEM                                  5 28-AUG-01

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> begin
  2    for x in ( select * from all_users where username in
  3                   ( select *
  4                        from THE ( select cast( in_list('OPS$TKYTE, SYS, SYSTEM')
  5                                as mytableType ) from dual ) )
  6             )
  7    loop
  8      dbms_output.put_line( x.username );
  9    end loop;
 10  end;
 11  /
OPS$TKYTE
SYS
SYSTEM

PL/SQL procedure successfully completed.


that shows its no different in plsql than sql. 

Very Cool, just what I need

Paul Duer, December 07, 2001 - 10:08 am UTC

I really like this example, but I have a bit of a silly question I am afraid.

What if I need to send a select statement to the IN clause? So that instead of selecting from a set of variables, I would select from a subquery, but have the ability to change the subquery to multiple different ones?

Is this possible?

Tom Kyte
December 07, 2001 - 11:34 am UTC

ops$tkyte@ORA817DEV.US.ORACLE.COM> create or replace
  2  function in_list( p_string in varchar2 ) return myTableType
  3  as
  4          type rc is ref cursor;
  5      l_cursor     rc;
  6      l_tmp        long;
  7      l_data       myTableType := myTableType();
  8  begin
  9    open l_cursor for p_string;
 10    loop
 11        fetch l_cursor into l_tmp;
 12        exit when l_cursor%notfound;
 13        l_data.extend;
 14        l_data(l_data.count) := l_tmp;
 15   end loop;
 16   close l_cursor;
 17   return l_data;
 18  end;
 19  /

Function created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> select *
  2    from table( cast( in_list( 'select 1 from dual' ) as myTableType )  )
  3  /

COLUMN_VAL
----------
1

ops$tkyte@ORA817DEV.US.ORACLE.COM> select *
  2    from table( cast( in_list( 'select ename from emp' ) as myTableType )  )
  3  /

COLUMN_VAL
----------
A
ALLEN
WARD
JONES
MARTIN
BLAKE
CLARK
SCOTT
KING
TURNER
ADAMS
JAMES
FORD
MILLER
ant
ant

16 rows selected. 

Could I pass a refcursor?!

Niloufar, October 11, 2002 - 12:55 pm UTC

Tom,

Thank you again for providing us with very helpful information.

Could this function be written such that it accepts a refcursor? I'd like to pass a refcursor that contains a list of order numbers to this function and in return be able to use that list in the IN CLAUSE of a SELECT statement in a procedure. Here is what I am trying to achieve:

-- Call to a procedure that returns the refcursor (c_order)
-- which contains the list of order numbers.

call_api.find_order_p(p_start_date, p_end_date, c_order);

-- Fetch the refcursor content into c_order_list which is
-- a PL/SQL:
-- TYPE OrderList IS TABLE OF VARCHAR2(15) INDEX BY BINARY_INTEGER;

-- The anyTableType is a SQL type TABLE OF VARCHAR2(2000);

c_data anyTableType := anyTableType();

FETCH c_order BULK COLLECT INTO c_order_list;
FOR i IN 1..c_order_list.COUNT LOOP
c_data.EXTEND;
c_data(c_data.COUNT) := c_order_list(i);
dbms_output.put_line('Post C_DATA is: '||c_data(c_data.COUNT));
END LOOP;

CLOSE c_order;

From here, I'd like to be able to use the result that is in c_data in the "IN CLAUSE" of another SQL statement that is used for another refcursor. In other words:

OPEN result_set FOR
'SELECT * FROM order WHERE order_num IN (the list in c_data)';

Is this possible? Am I doing this right?

Thank you.

Tom Kyte
October 11, 2002 - 8:39 pm UTC

In 9i, sure -- but with your example, you don't need to.

You would write a procedure that called "find_order_p", built the collection and returned it -- just like my in_list function does.

ORA-00600 when creating and describing a NT

Robert C, October 12, 2002 - 6:55 pm UTC

Tom, the error I got below...Is this BAD news ?
Do you know what's going on ?

LMS1@dns > create or replace type typeNestedTableVarchar_255 as table of varchar2(255)
/
create or replace type typeNestedTableVarchar_255 as table of varchar2(255)
*
ERROR at line 1:
ORA-00600: internal error code, arguments: [6002], [32], [6], [2], [0], [], [], []


"SCRP_CTR_TableType" has been in use successfully as a
dynamic in_list solution as you demoed sometime ago...
but when I desc it now....

LMS1@dns > desc SCRP_CTR_TableType
ERROR:
OCI-21500: internal error code, arguments: [koxsihread1], [0], [0], [4], [], [], [], []

And just now I exit the server is telling me this:
Disconnected from Oracle8i....<snip>
....64bit Production (with complications) <-- !

Wow...did I just screw up something ?


Tom Kyte
October 14, 2002 - 7:14 am UTC

well, I would contact support -- the issues I see surrounding this all seem related to an upgrade that wasn't done 100% right -- you don't mention an upgrade (or os, or version, or ... ) so you'll need to open a tar and see what they say.

Using BULK COLLECT in the In_list function.

Robert C, October 12, 2002 - 7:56 pm UTC

Tom, sorry, another thought...
I am trying to modify your In_List function to use BULK COLLECT, but can't make it work, Oracle complain about:
"ORA-01001: invalid cursor"

FETCH l_cursor BULK COLLECT INTO l_data_list ; --l_tmp;

Is BULK COLLECT available for this purpose ?

thanks

Tom Kyte
October 14, 2002 - 7:15 am UTC

how's about the entire example as I've no idea what code might possiblly have preceded this.

BULK COLLECT with Cursor Variable

Robert C, October 14, 2002 - 9:30 am UTC

>>Followup:
>>how's about the entire example as I've no idea what code >>might possiblly have preceded this.

Thanks Tom, basically my question was about using BULK COLLECT with Cursor Variable and subsequent search on this site I learned that this can not be done in 8i.



Tom Kyte
October 14, 2002 - 9:51 am UTC

Yes, it can  -- just NOT with a dynamically opened ref cursor.


ops$tkyte@ORA817DEV.US.ORACLE.COM> declare
  2          type rc is ref cursor;
  3          type array is table of varchar2(1) index by binary_integer;
  4
  5          l_cur rc;
  6          l_array array;
  7  begin
  8          open l_cur for select * from dual;
  9          begin
 10                  fetch l_cur BULK COLLECT into l_array;
 11                  dbms_output.put_line( 'Fetched ' || L_array.count || ' rows' );
 12          exception
 13                  when others then
 14                          dbms_output.put_line( 'ERROR: ' || sqlerrm );
 15          end;
 16          close l_cur;
 17
 18          open l_cur for 'select * from dual';
 19          begin
 20                  fetch l_cur BULK COLLECT into l_array;
 21                  dbms_output.put_line( 'Fetched ' || L_array.count || ' rows' );
 22          exception
 23                  when others then
 24                          dbms_output.put_line( 'ERROR: ' || sqlerrm );
 25          end;
 26          close l_cur;
 27  end;
 28  /
Fetched 1 rows
ERROR: ORA-01001: invalid cursor

PL/SQL procedure successfully completed.




static open, works, dynamic open, fails.

In 9i:

ops$tkyte@ORA9I.WORLD> ops$tkyte@ORA9I.WORLD> ops$tkyte@ORA9I.WORLD> declare
  2          type rc is ref cursor;
  3          type array is table of varchar2(1) index by binary_integer;
  4
  5          l_cur rc;
  6          l_array array;
  7  begin
  8          open l_cur for select * from dual;
  9          begin
 10                  fetch l_cur BULK COLLECT into l_array;
 11                  dbms_output.put_line( 'Fetched ' || L_array.count || ' rows' );
 12          exception
 13                  when others then
 14                          dbms_output.put_line( 'ERROR: ' || sqlerrm );
 15          end;
 16          close l_cur;
 17
 18          open l_cur for 'select * from dual';
 19          begin
 20                  fetch l_cur BULK COLLECT into l_array;
 21                  dbms_output.put_line( 'Fetched ' || L_array.count || ' rows' );
 22          exception
 23                  when others then
 24                          dbms_output.put_line( 'ERROR: ' || sqlerrm );
 25          end;
 26          close l_cur;
 27  end;
 28  /
Fetched 1 rows
Fetched 1 rows

PL/SQL procedure successfully completed.


both work 

varying elements in IN list

Rizwan Qazi, December 27, 2002 - 10:27 am UTC

Tom,
Thanks again for this great forum!
I have a dynamic sql (a part of which is given below). I have used your example to bind the columns using contexts.
Now I have a problem, how to bind the values in a for loop below.
Can you please help me out?



IF (p_selected_feature_set <> '0' AND p_selected_feature_set <> '-1') THEN
dbms_session.set_context( 'feat_utils_ctx', 'fs', p_selected_feature_set);
sql_image_ids := sql_image_ids || ' AND i.feature_set_id IN ' ;
sql_image_ids := sql_image_ids || ' ( select * from THE ( select cast( in_list(sys_context(''feat_utils_ctx'', ''fs'')) as idTableType ) from dual ) a ) ' ;
END IF;

sql_image_ids := sql_image_ids || ' AND EXISTS ( ';

FOR i IN 1..v_image_count LOOP

sql_temp_image_ids := sql_temp_image_ids || ' SELECT ';
sql_temp_image_ids := sql_temp_image_ids || ' 1 ';
sql_temp_image_ids := sql_temp_image_ids || ' FROM ';
sql_temp_image_ids := sql_temp_image_ids || ' fa_feature fa ';
sql_temp_image_ids := sql_temp_image_ids || ' WHERE ';
sql_temp_image_ids := sql_temp_image_ids || ' fa.feature_id = ( ' || TO_NUMBER(vit_image_ids(i)) || ') ';
sql_temp_image_ids := sql_temp_image_ids || ' AND fa.image_id = i.image_id ';

IF (i < v_image_count) THEN
sql_temp_image_ids := sql_temp_image_ids || ' INTERSECT ' ;
END IF;

END LOOP;

As you can see there is an intersect between two statements in the loop.

Tom Kyte
December 27, 2002 - 11:28 am UTC

actually -- i cannot see much as it wraps pretty badly

not really sure what you are trying to do. Maybe if you post it as a new question when I'm taking questions....

ORA-03113 while using the cast to table...

KU, December 27, 2002 - 6:26 pm UTC

O Oracle of Oracle,

I tried the following:
create type vc_array as table of varchar2(2000);

SELECT t.column_value
FROM table(cast(in_list('123,234') as VC_ARRAY)) t
;

COLUMN_VALUE
------------
123
234

So far so good.

My next query
SELECT
distinct
pol_id
FROM pol_ent
WHERE ent_id IN
(SELECT t.column_value
FROM table(cast(in_list('829740,1234') as vc_array)) t)
;
crashes with ORA-03113 (end of communicaion channel).

If I remove the 'distinct', it works, but I need the 'distinct' key word.

My actual query has this sql as a subquery, as in

select col1, col2, col3 from pol where polid in
(SELECT
--distinct
pol_id
FROM pol_ent
WHERE ent_id IN
(SELECT t.column_value
FROM table(cast(in_list('829740,1234') as vc_array)) t)
)
;

crashes all the time (with or without distinct/orderby/groupby) with ORA-03113.

(Database has abundant memory allocation to largepool, shared pool, javapool etc and db is java enabled).

The whole query works if there is no table(cast(... thing.

What shall I do to get around this error?

Regards

KU


Tom Kyte
December 28, 2002 - 9:34 am UTC

step 1: contact support and open a tar as you should for all ora-03113 and ora-00600 type errors

step 2: try this:

select col1, col2, col3 from pol where polid in
(SELECT
distinct
pol_id
FROM pol_ent
WHERE ent_id IN
(SELECT t.column_value
FROM table(cast(in_list('829740,1234') as vc_array)) t
where rownum > 0 )
)
;

or


select col1, col2, col3 from pol where polid in
(SELECT
distinct
pol_id
FROM pol_ent
WHERE ent_id IN
(SELECT t.column_value
FROM table(cast(in_list('829740,1234') as vc_array)) t
group by t.column_value )
)
;


Why

A reader, January 03, 2003 - 3:42 pm UTC

Hi, Tom,

I got this error in PLSQL when run your example:

FOR x IN (select *
from THE
( select cast( in_list('abc, xyz, 012') as
mytableType ) from dual ) a) LOOP
...
END LOOP;

ERROR:
PLS-00231:
function in_list may not be used in SQL

Please advice



forget above question

A reader, January 03, 2003 - 3:47 pm UTC

Hi, Tom,

Please forget that above question, the reason is
I have to declare IN_LIST() in the SPEC of a package
even it is only called within this package and there will be no other packages/procedures outside this package call the in_list() function, wired.

Thanks

Can somebody help me with those things?

Mike F., January 03, 2003 - 8:34 pm UTC

I don't know how the "THE" and "cast" work in the following:

select * from THE
( select cast( in_list('abc, xyz, 012') as
mytableType ) from dual ) a

Can Tom or anybody please point me in the right direction? Searching on the two words would be futile. Thanks!

Tom Kyte
January 04, 2003 - 9:20 am UTC

Ingore them -- they are the obsolete way.  Use this instead:

ops$tkyte@ORA817DEV> begin
  2          for x in ( select * from TABLE ( cast(in_list('abc,xyz,012') as myTabletype) ) )
  3          loop
  4                  dbms_output.put_line( x.column_value );
  5          end loop;
  6  end;
  7  /
abc
xyz
012

PL/SQL procedure successfully completed.


see
http://docs.oracle.com/docs/cd/A87860_01/doc/server.817/a85397/expressi.htm#1017895
for CAST documentation -- just a function to ensure a datatype:


ops$tkyte@ORA817DEV> select cast( '0' as number(7,2) ) from dual;

CAST('0'ASNUMBER(7,2))
----------------------
                     0


sort of a conversion function. 

By the way, a comment

Mike F., January 03, 2003 - 8:39 pm UTC


To put a result set returned from a stored function in
a "in" list would be so easy and nature in SQL Server.
Just define the stored function to return a table.
Then you can do this:

select * from my_table where col in my_func(arg)

or you can use this:

select t.* from my_table t, my_func(arg) f
where t.col = f.col

Tom Kyte
January 04, 2003 - 9:24 am UTC

  1* select * from all_users where user_id in (select * from TABLE(in_list('1,2,3,4,5')))
ops$tkyte@ORA920> /

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
SYSTEM                                  5 12-MAY-02

  1  select *
  2    from all_users, TABLE(in_list('1,2,3,4,5'))
  3*  where all_users.user_id = column_value
ops$tkyte@ORA920> /

USERNAME                          USER_ID CREATED   COLUMN_VALUE
------------------------------ ---------- --------- -------------------------
SYSTEM                                  5 12-MAY-02 5


not significantly different.  And it is standard (so it should theoritically work in all sql99 databases). 

Not very different, but

Mike F., January 08, 2003 - 3:27 pm UTC

Thanks, Tom.

The variable "in" list solution might look easy and
natural to you, but might not to some others:

1. One has to declare a global type just for the list
to be used in the "in" list. If one has many types
of such lists, the global space could be a bit clogged,
not a particular bad thing, but consider multi-column
in lists, it is not very pleasant as well.

2. I am not sure why one still needs to cast the return
value of in_list, which is already of type myTableType,
into myTableType again?

3. The result value of in_list is already a table, why would
we do the select like this: "select <table> from dual"
in order to make it into a "table"?

4. OK, assume you do need to do the above select, now one
might think now we have a result set that we can use "in",
just as in:

select * from all_users
where user_name in (select user_name in old_users)

Wrong again. One has to put a "table" keyword in front
of the result set in order to put it in the "in" list,
even though it is already a "table".

Quite a few tricks to learn, it seems. Let alone one might get lost about the concept of "table" itself. I doubt if many
Oracle developers know about these tricks. It is at least
not mentioned in any PL/SQL book I have read (at least 4 of them).




Tom Kyte
January 08, 2003 - 6:21 pm UTC

1) there are like three types in the world: strings, numbers and dates. 3 doesn't seem to be CLUTTER does it?

where does a multi-column inlist come from?

anyway, I think of them as views, views are metadata -- it is actually good documentation.

2) I'm not really worried about it -- I'd be worried if I couldn't do it. You know, for everything you think "oracle got wrong", I'll find at least one thing I think MS got wrong. We are *different* (thank goodness).

3) because it is officially a COLLECTION -- does SQL server have the concept of a collection? Like an array of values that can live in a row? A collection is a scalar type -- we turn it into a TABLE() by using TABLE.

4) It isn't a table (maybe it is the sql server limitation that is hiding that fact from you). It is a SCALAR -- like a NUMBER is. You have to convert it into a table.



You didn't read my book then!



Good info. Thanks.

Mike F., January 08, 2003 - 10:56 pm UTC


Tom,

Thanks a lot for your explanations. I was not implying that MS SQL Server is a better product.
Sure I am aware of many Oracle features that are
not supported in MS SQL Server. I just found it
easier for me to learn Oracle by comparing the two
and figuring out the differences. Maybe I wish
it could have done better in some areas.
That's about it.

One particular issue I am having with learning
Oracle is the documentations. I found it's a
little hard to navigate to where I need to know more
about. Probably it is the lack of good indexing
and searching capabilities in the docs?
Perhaps the sheer complexity of Oracle
prevents it to have something as organized
as SQL Server's Book On Line and Knowledgment Base?

One last question, in order to turn a "collection"
into a table, one need to do this:

TABLE (select <collection> from dual)

right? What's the rational, please? Thanks a lot!





Oh, so-called "multi-column in list"

Mike F., January 08, 2003 - 11:50 pm UTC

Tom,

Forgot to explain my so-called "multi-column in list". Please forgive the bad name. But here is what I mean:

select * from all_users
where (first_name, last_name)
in (select first_name, last_name from some_users)

Say, we have a stored function that returns a table (or a ref cursor) that has two columns (first_name, last_name). Now we want to make use of the stored function in the above select. My guess is that we need to turn the two column table, or collection, or whatever, into a real table somehow. To do this it seems to me we need an another table type for it, right? Sorry if I am wrong.

Tom Kyte
January 09, 2003 - 7:25 am UTC

Yes you do -- just like you would have to use a subquery -- or to simplify it you might use a view -- metadata.

Again, you would have a very finite set of these objects. Sorry - it is different but equivalent. We are not MS, they are not us. Different strokes for different folks.

Can I do this?

Mike F., January 12, 2003 - 10:14 pm UTC

Tom,

Now I have another question. Another way to do the following:

v_str := '1,2,3,4,5';
...
select count(*)
into v_cnt
from all_users
where user_id in
(select * from TABLE(in_list(v_str)))

seems to be:

v_str := '1,2,3,4,5';
...
select *
into v_cnt
from all_users
where instr(',' || v_str || ',',
',' || to_char(user_id) || ',') > 0

How do think about the this approach?
It seems to me pretty straightforward, and pretty
fast as well. Please comment. Thanks a lot!




Tom Kyte
January 13, 2003 - 7:52 am UTC

do it with 100,000 rows and tell me how fast it is.

where in () = possible to use index range scan on user_id

where instr() = NOT POSSIBLE to use index range scan on user_id

big_table@ORA920> set autotrace traceonly
big_table@ORA920> select *
2 from big_table
3 where id in ( select to_number(column_value)
4 from TABLE( cast(in_list('1,2,3,4,5,6,7,8,9,10') as myTableType) )
5 where rownum > 0
6 )
7 /

10 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=1672 Card=8168 Bytes=931152)
1 0 NESTED LOOPS (Cost=1672 Card=8168 Bytes=931152)
2 1 VIEW OF 'VW_NSO_1' (Cost=11 Card=8168 Bytes=106184)
3 2 SORT (UNIQUE)
4 3 COUNT
5 4 FILTER
6 5 COLLECTION ITERATOR (PICKLER FETCH) OF 'IN_LIST'
7 1 TABLE ACCESS (BY INDEX ROWID) OF 'BIG_TABLE' (Cost=2 Card=1 Bytes=101)
8 7 INDEX (UNIQUE SCAN) OF 'BIG_TABLE_PK' (UNIQUE) (Cost=1 Card=1)




Statistics
----------------------------------------------------------
22 recursive calls
0 db block gets
43 consistent gets
0 physical reads
0 redo size
1948 bytes sent via SQL*Net to client
499 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
6 sorts (memory)
0 sorts (disk)
10 rows processed

big_table@ORA920> select *
2 from big_table
3 where instr( ',' || '1,2,3,4,5,6,7,8,9,10' || ',', ',' || to_char(id) || ',' ) > 0
4 /

10 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=1253 Card=50000 Bytes=5050000)
1 0 TABLE ACCESS (FULL) OF 'BIG_TABLE' (Cost=1253 Card=50000 Bytes=5050000)




Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
13022 consistent gets
12170 physical reads
0 redo size
1948 bytes sent via SQL*Net to client
499 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
10 rows processed

big_table@ORA920> set autotrace off


Can not figure out the

Ivan, February 25, 2003 - 12:07 pm UTC

Hi Tom,

I am getting the PLS-00513: PL/SQL function called from SQL must return value of legal SQL type for my call to mev_sic.get_company_sic_info(co.company_id) from the select statement below. I realize what the problem is but I can not figure out how to create a table type like you described for more then one row (per your example for Niloufar). My table type needs to send more then one column.

TYPE CompanySicInfo_rectype IS RECORD
( sic_source sic_codes.sic_source%TYPE,
sic_code sic_codes.sic_code%TYPE,
industry_class_id sic_codes.industry_class_id%TYPE,
sic_type company_sic_codes.sic_type%TYPE,
short_description sic_codes.short_description%TYPE
);

TYPE SicCodeTblTyp IS TABLE OF CompanySicInfo_rectype
INDEX BY BINARY_INTEGER;


PROCEDURE get_company_dbupdate
( i_attr_info_tbl IN attr_name_value_tbltype,
i_matching_criteria IN POSITIVE,
o_company_info_rec OUT company_info_rectype,
o_company_sic_info OUT SicCodeTblTyp )
IS
v_attr_id identifying_attrs.attribute_id%TYPE;
v_attr_value company_attrs.attribute_value%TYPE;
v_company_id company_attrs.company_id%TYPE;
v_last_company_id company_attrs.company_id%TYPE;
i BINARY_INTEGER;
v_cnt_matches BINARY_INTEGER DEFAULT 0;
v_coa_rowid ROWID;
KeyIDConflicts BOOLEAN DEFAULT FALSE;
BEGIN
o_company_info_rec := NULL; -- Clear the output record
set_matching_criteria(i_matching_criteria);
FOR i IN 1..i_attr_info_tbl.COUNT LOOP
logedit_attr_value(i_attr_info_tbl(i).attr_name,i_attr_info_tbl(i).attr_value,v_attr_id,v_attr_value);
IF i_attr_info_tbl(i).attr_value IS NOT NULL THEN
BEGIN
SELECT
coa.ROWID,
co.company_id,
co.name,
co.address_1,
co.address_2,
co.city,
co.district,
co.country_id,
co.telephone_number,
co.business_description,
co.quotation_symbol,
co.parent_id_usage,
co.parent_id,
co.scale,
co.employees,
co.url,
igrp.industry_group_id,
igrp.industry_mnemonic,
igrp.name,
mev_sic.get_company_sic_info(co.company_id)
INTO
v_coa_rowid,
v_company_id,
o_company_info_rec.name,
o_company_info_rec.address_1,
o_company_info_rec.address_2,
o_company_info_rec.city,
o_company_info_rec.district,
o_company_info_rec.country_id,
o_company_info_rec.telephone_number,
o_company_info_rec.business_description,
o_company_info_rec.quotation_symbol,
o_company_info_rec.parent_id_usage,
o_company_info_rec.parent_id,
o_company_info_rec.scale,
o_company_info_rec.employees,
o_company_info_rec.url,
o_company_info_rec.industry_group_id,
o_company_info_rec.industry_mnemonic,
o_company_info_rec.industry_name,
o_company_sic_info
FROM
company_attrs coa,
companies co,
industry_groups igrp
WHERE coa.attribute_id = v_attr_id
AND coa.attribute_value = v_attr_value
AND coa.company_id = co.company_id
AND co.industry_group_id = igrp.industry_group_id (+);

IF UpdateReadDate THEN
UPDATE company_attrs
SET last_read_date = SYSDATE
WHERE ROWID = v_coa_rowid;
END IF;

IF MatchFirst THEN
v_cnt_matches := i;
EXIT;
ELSIF MatchAll THEN
v_cnt_matches := v_cnt_matches + 1;
IF v_last_company_id IS NULL THEN
v_last_company_id := v_company_id;
END IF;

IF v_company_id <> v_last_company_id THEN
KeyIDConflicts := TRUE;
END IF;
END IF;
EXCEPTION
WHEN no_data_found THEN
NULL;
END;
END IF;
END LOOP;
mev_common.perform_commit;
o_company_info_rec.matching_attr := v_cnt_matches;

IF KeyIDConflicts THEN
o_company_info_rec.company_id := -1;
o_company_info_rec.name := NULL;
ELSE
o_company_info_rec.company_id := v_company_id;
END IF;
EXCEPTION
WHEN others THEN
mev_common.perform_rollback;
mev_audit.sql_error;
RAISE;
END get_company_dbupdate;

Thanks as always,
Ivan





Tom Kyte
February 25, 2003 - 7:59 pm UTC

sorry -- not making sense -- need a small (much smaller) yet COMPLETE example

You cannot -- repeat cannot -- use plsql record types in sql, you must MUST use object types created in sql, not plsql.

Also -- it is really hard to see what the function in question does -- since it isn't there.

So -- use sql object types.
Create a small, yet 100% complete example

Please disregard my post above...

Ivan, February 25, 2003 - 4:00 pm UTC

I have figured out my problem.

Thanks,

Ivan

How to use list generated by select

hk, March 03, 2003 - 8:07 pm UTC


select * from entry_in_group where group_id in (select * from THE ( select cast(str2tbl('10, 20, 30') as mytableType ) from dual ) )

ENTRY_ID GROUP_ID
---------- ----------
1000002 10
1000004 10
1000003 20


Why this is not working(no rows returned):

select * from entry_in_group where group_id in (select * from THE ( select cast(str2tbl('select * from test') as mytableType ) from dual ) )


select * from test;
ASD
-----------------
10,20,30


Tom Kyte
March 04, 2003 - 6:51 am UTC

because that was just saying:

select * from entry_in_group
where group_id in ( 'select', '*', 'from', 'test' );


what might work -- didn't try it, would be:

select * from entry_in_group where group_id in (select * from THE ( select
cast(str2tbl( (select * from test) ) as mytableType ) from dual ) )


using a scalar subquery.

...

hk, March 04, 2003 - 9:00 am UTC


It worked, thanks!

Problem implementing cast

Max, March 21, 2003 - 1:41 pm UTC

Tom,

I have a query which returns me the list of items from various tables for an order. While processing my order, I frequently need these list of items -- sometimes a count and sometimes the actual items. So in various sqls I have this common where clause, "where item in (select item ...<common query>)".

How can I avoid executing this common query multiple times ? I tried collecting this item list into an array using bulk fetch but could not implement further using cast. Can you please help ?

select count(*) ctr from itempack
where packid in
( /* this is the common query block */
select item
from orditem
where order_nbr = I_order_nbr
union
select item
from orditem_tmp
where order_nbr = I_order_nbr);

Thanks in advance !

Tom Kyte
March 21, 2003 - 2:24 pm UTC

why couldn't you implement further?

show us what you tried -- make it as teeny tiny as possible. 9999 times out of 10000 -- I find my mistake coming up with a small test case to demonstrate my issue. hopefully you will too -- but if not, post your teeny tiny example here.



Here is what I tried

Max, March 21, 2003 - 2:46 pm UTC

Ok, here is what i tried. For testing purpose, I am trying to get the count. If I am able to achieve this, I can use it further in my package. I know I am not able to implement table/cast correctly.

declare
cursor c_items is
select item
from orditem
where order_nbr = 18312
union
select item
from orditem_tmp
where order_nbr = 18312;

TYPE itemList IS TABLE OF item_mst.item%TYPE;
item_arr itemList;
ctr number;
begin
open c_items;
fetch c_items bulk collect into item_arr;
close c_items;

select count(*) into ctr
from table(cast(L_sku_arr as number));
end;
/


Tom Kyte
March 21, 2003 - 2:58 pm UTC

the type MUST be a SQL type -- just like my example above is.


SQL> create or replace type myTableType as table 
     of varchar2 (255);
  2  /


and oh, 

  l_sku_array.count

would be infinitely less resource intensive then "select count(*)"  

Max, March 21, 2003 - 3:22 pm UTC

Ok, I created the type as below.

create or replace type myTableType as table of varchar2(255)
/

Ran the script and still getting the below error :(

select count(*) into ctr from TABLE(cast(item_arr as myTableType));
*
ERROR at line 23:
ORA-06550: line 23, column 44:
PLS-00382: expression is of wrong type
ORA-06550: line 23, column 3:
PL/SQL: SQL Statement ignored

What exactly should I change in my script to make it working ???

and oh, I knew you would ask me to use "count" thats why I mentioned "For testing purpose, I am trying to get the count" in the beginning.

Tom Kyte
March 21, 2003 - 3:48 pm UTC

ops$tkyte@ORA817DEV> create or replace type myTableType as table of varchar2(255)
  2  /

Type created.

ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV> declare
  2          l_data myTableType;
  3          l_cnt  number;
  4  begin
  5          select username bulk collect into l_data
  6            from all_users;
  7
  8          select count(*) into l_cnt
  9            from TABLE( cast( l_data as myTableType ) );
 10  end;
 11  /

PL/SQL procedure successfully completed.





 

Thank You Thank You Thank You Very Much !!!

Max, March 21, 2003 - 3:58 pm UTC

It worked ! I am a happy camper now -- you made my friday & weekend :-)

Does the type myTableType have to be in the database only ? I tried defining the type in the pl/sql script but get an error "local collection types not allowed in SQL statements".

I dont know, but I am finding it HARD to understand the TABLE/CAST usage from the documentation :( Any tips to overcome this Tom ???

Tom Kyte
March 21, 2003 - 4:35 pm UTC

the type MUST be a SQL type -- just like my example above is.


SQL> create or replace type myTableType as table 
     of varchar2 (255);
  2  /

it cannot be a plsql type.


cast just "casts", you can

ops$tkyte@ORA920> select cast( 1.4213234 as number(7,2) ) from dual;

CAST(1.4213234ASNUMBER(7,2))
----------------------------
                        1.42

TABLE() just takes a collection and says "pretend it is a table"
 

How to compare arrays ???

Max, March 26, 2003 - 5:59 pm UTC

Hi Tom,

First of all, THANKS for all the answers -- they were extremly useful & helped me tune my pl/sql scripts. But then, one solution leads to another question ;)

Now say I want to find if an element in the 1st array exists in the 2nd array. I achieved that by writing the below code -- works fine & gives me what I want.

for i in 1..L_newsku_arr.last loop
for j in 1..L_ordsku_arr.last loop
if L_ordsku_arr(j) = L_newsku_arr(i) then
dbms_output.put_line('match found for '||L_newsku_arr(i));
exit;
end if;
end loop;
end loop;

Would it give better performance if I write a sql to find the match ? Also, I had trouble getting the column name when I cast the array to a table.

select * from TABLE(cast(L_newsku_arr as myTableType));

Thanks !

Tom Kyte
March 26, 2003 - 7:05 pm UTC

ops$tkyte@ORA920> create or replace
  2  procedure isIn_procedural( p_array1 in numArray,
  3                             p_array2 in numArray,
  4                             p_print in boolean default false )
  5  is
  6  begin
  7      for i in 1 .. p_array1.count
  8      loop
  9          for j in 1 .. p_array2.count
 10          loop
 11              if ( p_array1(i) = p_array2(j) )
 12              then
 13                  if ( p_print )
 14                  then
 15                      dbms_output.put_line
 16                      ( 'Matched ' || p_array1(i) );
 17                  end if;
 18                  exit;
 19              end if;
 20          end loop;
 21      end loop;
 22  end;
 23  /

Procedure created.

Elapsed: 00:00:00.18
ops$tkyte@ORA920>
ops$tkyte@ORA920> create or replace
  2  procedure isIn_sql( p_array1 in numArray,
  3                      p_array2 in numArray,
  4                      p_print in boolean default false )
  5  is
  6  begin
  7      for x in ( select * from TABLE(cast(p_array1 as numArray))
  8                 intersect
  9                 select * from TABLE(cast(p_array2 as numArray)) )
 10      loop
 11          if ( p_print )
 12          then
 13              dbms_output.put_line( 'Matched ' || x.column_value );
 14          end if;
 15      end loop;
 16  end;
 17  /

Procedure created.

Elapsed: 00:00:00.19
ops$tkyte@ORA920>
ops$tkyte@ORA920> set timing on
ops$tkyte@ORA920> declare
  2      l_array1 numArray := numArray();
  3      l_array2 numArray := numArray();
  4  begin
  5      for i in 1 .. 200
  6      loop
  7          l_array1.extend;
  8          l_array1(l_array1.count) := i;
  9          if ( mod(i,2) = 0 )
 10          then
 11              l_array2.extend;
 12              l_array2(l_array2.count) := i;
 13          end if;
 14      end loop;
 15
 16      for i in 1 .. 500
 17      loop
 18          isIn_Procedural(l_array1,l_array2);
 19      end loop;
 20  end;
 21  /

PL/SQL procedure successfully completed.

Elapsed: 00:00:14.79
ops$tkyte@ORA920> declare
  2      l_array1 numArray := numArray();
  3      l_array2 numArray := numArray();
  4  begin
  5      for i in 1 .. 200
  6      loop
  7          l_array1.extend;
  8          l_array1(l_array1.count) := i;
  9          if ( mod(i,2) = 0 )
 10          then
 11              l_array2.extend;
 12              l_array2(l_array2.count) := i;
 13          end if;
 14      end loop;
 15
 16      for i in 1 .. 500
 17      loop
 18          isIn_SQL(l_array1,l_array2);
 19      end loop;
 20  end;
 21  /

PL/SQL procedure successfully completed.

Elapsed: 00:00:01.94
 

A reader, March 27, 2003 - 12:01 am UTC

hhmmm ! So for the query "select * from TABLE(cast(p_array1 as numArray))", the column name is column_value. Is that right ?

Had you not been there Tom, we would have never known. Where in the world is this mentioned in the Oracle documentation ???

Tom Kyte
March 27, 2003 - 7:46 am UTC

http://docs.oracle.com/docs/cd/A87860_01/doc/appdev.817/a76976/adobjvew.htm#434487 http://docs.oracle.com/docs/cd/A87860_01/doc/appdev.817/a76976/adobjadv.htm#1002819


or, by discovery:

ops$tkyte@ORA920> create or replace type array as table of number
  2  /
Type created.


ops$tkyte@ORA920> select * from table(array(1));
<b>
COLUMN_VALUE</b>
------------
           1


ops$tkyte@ORA920> variable x refcursor

ops$tkyte@ORA920> declare
  2      l_data array := array(1,2,3);
  3  begin
  4      open :x for
  5      select * from TABLE( cast( l_data as array ) );
  6  end;
  7  /
PL/SQL procedure successfully completed.

ops$tkyte@ORA920> print x

<b>COLUMN_VALUE</b>
------------
           1
           2
           3

ops$tkyte@ORA920> create or replace function f return array
  2  as
  3  begin
  4      return null;
  5  end;
  6  /
Function created.

ops$tkyte@ORA920> create or replace view v
  2  as
  3  select * from table( cast( f as array ) );

View created.

ops$tkyte@ORA920>
ops$tkyte@ORA920> desc v
 Name                          Null?    Type
 ----------------------------- -------- --------------------<b>
 COLUMN_VALUE                    </b>       NUMBER


ops$tkyte@ORA920> declare
  2      l_theCursor     integer default dbms_sql.open_cursor;
  3      l_colCnt        number := 0;
  4      l_descTbl       dbms_sql.desc_tab;
  5  begin
  6      dbms_sql.parse(  l_theCursor,
  7                          'select * from table( array(1,2,3) )',
  8                                           dbms_sql.native );
  9
 10      dbms_sql.describe_columns
 11          ( l_theCursor, l_colCnt, l_descTbl );
 12
 13      for i in 1 .. l_colCnt loop
 14          dbms_output.put_line( l_descTbl(i).col_name );
 15      end loop;
 16  end;
 17  /<b>
COLUMN_VALUE
</b>
PL/SQL procedure successfully completed. 

wow ! more than most useful ...

Max, March 27, 2003 - 8:48 am UTC

Tom, you are great with examples -- just no words to praise and much more than 5 stars to rate your answers.

RE: myTableType data type

Max, March 27, 2003 - 11:58 am UTC

Tom, does it matter what type myTableType is ? I tried switching it between varchar2(255) & number and the script just ran fine -- so I have just kept it as varchar2(255).

Tom Kyte
March 27, 2003 - 12:36 pm UTC

if you use delimited strings of numbers -- "table of number" works dandy. If you use strings as my example did, it would not work.

Murugan, March 27, 2003 - 7:02 pm UTC

Thomas, you can try this too.


SQL> select job, count(*)
  2  from emp
  3  group by job
  4  /

JOB        COUNT(*)
--------- ---------
ANALYST           4
CLERK             7
MANAGER           3
PRESIDENT         1
SALESMAN          4


SQL> declare
  2    v_char  varchar2(100) := '''CLERK'', ''SALESMAN'', ''PRESIDENT''';
  3    v_count number;
  4  begin
  5    select count(*)
  6    into v_count
  7    from emp
  8    where instr(v_char, ''''||job||'''') > 0;
  9    dbms_output.put_line('Count: '||v_count);
 10  end;
 11  /
Count: 12 

Tom Kyte
March 27, 2003 - 7:32 pm UTC

sure -- but consider if

o emp has more then a toy amount of data...
o the thing you IN on should use an index...
o you preclude that from being possible...

That is the objective here -- to use a true IN, not apply a function to the column and preclude an index path.

Just a Query?

SD, April 16, 2003 - 5:29 am UTC

What is the diff. between a Collection and an Object type
When I say

create or replace type bat_type as table of number (9) index by binary_integer ;
it creates it as object type
and
create or replace type bat_type as table of number (9) ;
gets created as collection , why?

Tom Kyte
April 16, 2003 - 10:10 am UTC

funny, when I do it:

  1* create or replace type bat_type as table  of number (9) index by binary_integer
ops$tkyte@ORA920LAP> /

Warning: Type created with compilation errors.

ops$tkyte@ORA920LAP> show err
Errors for TYPE BAT_TYPE:

LINE/COL ERROR
-------- -----------------------------------------------------------------
0/0      PL/SQL: Compilation unit analysis terminated
1/18     PLS-00355: use of pl/sql table not allowed in this context


I get an error.  index by binary_integer is valid ONLY in plsql -- it is a plsql index by table.

A collection defined using CREATE TYPE is an object type.

 

New feature

Martin, April 16, 2003 - 11:49 am UTC

Tom, the CREATE TYPE .. INDEX BY BINARY_INTEGER is a 10i feature. Didn't you know that? ;-)

Sorry

SD, April 17, 2003 - 5:32 am UTC

I'm sorry for this stupid mistake, actually I was using some third party tool and it showed me under Object_type but did not give any compilation error, but after looking into it I found that the complete attribute was False. Thanks for your support.
Thanks Martin ;)

Good technique, but watch out for partitions

Basil, April 18, 2003 - 3:41 pm UTC

I've been making heavy use of the IN (SELECT * FROM TABLE(CAST (x AS numTableType))) for a while now. However, I recently converted the most critical tables involved to list-based partitioned tables (I'm running 9.2.0.1.0).

If I partition my table (containing perhaps 30 million rows) on, say, cust_id, running a query like this:

INSERT INTO targettable
SELECT * FROM srctable WHERE cust_id IN (SELECT * FROM TABLE(CAST( x AS numTableType)))

is taking some 4 minutes to run, when x contains one value representing 80,000 rows out of the 30 million.

Re-doing the query as dynamic SQL doing something like:
INSERT INTO targettable
SELECT * FROM srctable WHERE cust_id IN (42);

is taking 28 seconds to run for the same volume of data. This is all running on a laptop - P4 2 GHz, 1 MB RAM, 400 MB or so SGA for Oracle.

Examining the trace files with tkprof reveals that the first query isn't pruning partitions, while the second one is. Ouch.



ORA-06530

Paul, June 02, 2003 - 6:07 am UTC

Tom,

I am trying to use this method for a similar problem (in 8.1.7.4). I have a string that contains pairs of data, so that I would want to convert 12345,A,23456,B,67890,C to

12345 A
23456 B
67890 C

No problemo, I thought, but when I do the following, I get the ORA-06530 error:

create or replace type my_obj as object(
col1 varchar2(20),
col2 varchar2(1)
)
/
create or replace type my_tab_type as table of my_obj
/

create or replace function f_my_convert(
p_string in varchar2
)
return my_tab_type as
l_string varchar2(2000) default p_string || ',';
l_data my_tab_type := my_tab_type();
l_instr number;
begin
loop
exit when l_string is null;
l_data.extend;
-- first in pair
l_instr := instr(l_string,',');
l_data(l_data.count).col1 := trim(substr(l_string,1,l_instr - 1));
l_string := substr(l_string,l_instr + 1);
-- second in pair
l_instr := instr(l_string,',');
l_data(l_data.count).col2 := trim(substr(l_string,1,l_instr - 1));
l_string := substr(l_string,l_instr + 1);
end loop;
return l_data;
end;
/

select *
from the
( select cast( f_my_convert('12345,A,23456,B,67890,C') as
my_tab_type ) from dual ) a
/

I know I must be doing something stupid, but I can't see what. I'd be grateful if you had any ideas.

Thanks

Tom Kyte
June 02, 2003 - 7:44 am UTC

you are getting:

        ( select cast( f_my_convert('12345,A,23456,B,67890,C') as
                       *
ERROR at line 3:
ORA-06530: Reference to uninitialized composite
ORA-06512: at "OPS$TKYTE.F_MY_CONVERT", line 14

you are missing the setting of the i'th element of the collection to an empty object instance:

   loop
      exit when l_string is null;
      l_data.extend;
<b>      l_data(l_data.count) := my_obj(null,null);</b>
 

Paul

Paul, June 02, 2003 - 8:25 am UTC

Thanks very much (again!!!)

Paul

arguments to a proceudre

santhanam, August 19, 2003 - 3:27 am UTC

Excellent
thanks tom

Rick, August 20, 2003 - 12:50 pm UTC

Thanks Tom,   

I have implemented this method where the application passes in a string of IDs.  This has helped solve a few problems.  

One thing I have noticed is performance is not very good using the STR2TBL function and MYTABLETYPE collection.  Here is what I have. 

Table is:
SQL> desc CNA;
 Name               Null?    Type
 ------------------ -------- ------------
 CNA_ID             NOT NULL NUMBER(15)
 NOTIFYAPPROVETYPE  NOT NULL NUMBER(2)
 DELETED            NOT NULL NUMBER(2)
 CNA_WHO_ID         NOT NULL NUMBER(15)
 CNA_WHO_TYPE       NOT NULL NUMBER(15)
 ASSOC_ID1          NOT NULL NUMBER(15)
 ASSOC_ID2          NOT NULL NUMBER(15)
 ASSOC_ID3          NOT NULL NUMBER(15)

SQL> select count(1) from CNA;

  COUNT(1)
----------
    122827

COL INDEX_NAME format A30 heading 'INDEX_NAME' 
COL COLUMN_NAME format A30 heading 'COLUMN_NAME' 
COL COLUMN_POSITION format 99 heading 'COLUMN_POSITION' 

SQL> select INDEX_NAME, COLUMN_NAME, COLUMN_POSITION
  2   from user_ind_columns where table_name = 'CNA';

INDEX_NAME       COLUMN_NAME    COLUMN_POSITION
---------------- -------------- ---------------
PK_CNA         CNA_ID         1

AK_CNA_EMP       CNA_WHO_ID     1
AK_CNA_EMP       CNA_WHO_TYPE   2

AK_CNA_ASSOC     ASSOC_ID1      1
AK_CNA_ASSOC     ASSOC_ID2      2
AK_CNA_ASSOC     ASSOC_ID3      3
AK_CNA_ASSOC     DELETED        4

AK_CNA_ASSOC2    ASSOC_ID2      1
AK_CNA_ASSOC3    ASSOC_ID3      1


Now I do use variables for the IN statements and the Count  (The values in the IN statements may be different for each ASSOC_ID but are the same in this case).

The query looks like this:

SQL> SELECT   NOTIFYAPPROVETYPE, CNA_WHO_ID, CNA_WHO_TYPE
  2      FROM CNA 
  3     WHERE DELETED = 0
  4       AND ASSOC_ID1 IN (0,4525, 420, 81644)
  5       AND ASSOC_ID2 IN (0,4525, 420, 81644)
  6       AND ASSOC_ID3 IN (0,4525, 420, 81644)
  7  GROUP BY NOTIFYAPPROVETYPE,
  8           CNA_WHO_ID,
  9           CNA_WHO_TYPE
 10    HAVING COUNT (1) > (0)
 11  ORDER BY 3;

NOTIFYAPPROVETYPE CNA_WHO_ID CNA_WHO_TYPE
----------------- ---------- ------------
                2       3984            1
                2       9569            1
                2      23805            1
                2      24061            1
                2      29514            1
                2      35844            1
                2      36816            1
                2      38201            1
                2      38612            1
                2      38824            1
                2      39739            1
                2      42216            1
                2      53138            1

13 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=5 Card=1 Bytes=18)
   1    0   FILTER
   2    1     SORT (GROUP BY) (Cost=5 Card=1 Bytes=18)
   3    2       INLIST ITERATOR
   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'CNA' (Cost=3 Card=1 Bytes=18)
   5    4           INDEX (RANGE SCAN) OF 'AK_CNA_ASSOC' (NON-UNIQUE) (Cost=2 Card=1)


Here is the Query with the Function and Collection:


SQL> SELECT   NOTIFYAPPROVETYPE, CNA_WHO_ID, CNA_WHO_TYPE
  2      FROM CNA 
  3     WHERE DELETED = 0
  4       AND ASSOC_ID1 IN (SELECT *
  5                           FROM THE (SELECT CAST 
  6           (STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
  7                           FROM DUAL))
  8       AND ASSOC_ID2 IN (SELECT *
  9                           FROM THE (SELECT CAST 
 10           (STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
 11                           FROM DUAL))
 12       AND ASSOC_ID3 IN (SELECT *
 13                           FROM THE (SELECT CAST 
 14           (STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
 15                           FROM DUAL))
 16  GROUP BY NOTIFYAPPROVETYPE,
 17           CNA_WHO_ID,
 18           CNA_WHO_TYPE
 19    HAVING COUNT (1) > (0)
 20  ORDER BY 3;

NOTIFYAPPROVETYPE CNA_WHO_ID CNA_WHO_TYPE
----------------- ---------- ------------
                2       3984            1
                2       9569            1
                2      23805            1
                2      24061            1
                2      29514            1
                2      35844            1
                2      36816            1
                2      38201            1
                2      38612            1
                2      38824            1
                2      39739            1
                2      42216            1
                2      53138            1

13 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=19871045 Card=52 Bytes=2964)
   1    0   FILTER
   2    1     SORT (GROUP BY) (Cost=19871045 Card=52 Bytes=2964)
   3    2       HASH JOIN (Cost=47803 Card=697807331 Bytes=39775017867)
   4    3         VIEW OF 'VW_NSO_3' (Cost=21 Card=8168 Bytes=106184)
   5    4           SORT (UNIQUE) (Cost=21 Card=8168 Bytes=16336)
   6    5             COLLECTION ITERATOR (PICKLER FETCH)
   7    6               TABLE ACCESS (FULL) OF 'DUAL' (Cost=1 Card=1)
   8    3         HASH JOIN (Cost=1156 Card=19051302 Bytes=838257288)
   9    8           VIEW OF 'VW_NSO_1' (Cost=21 Card=8168 Bytes=106184)
  10    9             SORT (UNIQUE) (Cost=21 Card=8168 Bytes=16336)
  11   10               COLLECTION ITERATOR (PICKLER FETCH)
  12   11                 TABLE ACCESS (FULL) OF 'DUAL' (Cost=1 Card=1)
  13    8           HASH JOIN (Cost=95 Card=545789 Bytes=16919459)
  14   13             VIEW OF 'VW_NSO_2' (Cost=21 Card=8168 Bytes=106184)
  15   14               SORT (UNIQUE) (Cost=21 Card=8168 Bytes=16336)
  16   15                 COLLECTION ITERATOR (PICKLER FETCH)
  17   16                   TABLE ACCESS (FULL) OF 'DUAL' (Cost=1 Card=1)
  18   13             TABLE ACCESS (FULL) OF 'CNA' (Cost=40 Card=61408 Bytes=1105344)

Database is currently 8.1.7.4.  We will be moving to 9iR2 the first of the year.

Thanks for your time.



 

Tom Kyte
August 21, 2003 - 5:02 pm UTC

it doens't know the cardinality of the str2tbl and is guessing 8,168 rows.

i would do two things:

a) add "where rownum >= 0" to the subqueries
b) add /*+ FIRST_ROWS */ to the outer query

Rick, August 21, 2003 - 8:10 pm UTC

Didn't Help. I got the same execution plan as without the "where rownum >= 0" and "/*+ FIRST_ROWS */ "
I even tried it with a hint to use the index. The query is not all that bad now. But it is one of the heavier ones and it gets executed about 400-500 times a day. The table growth is about 20K rows a month so it will just keep getting worse. I have built a test script to help.

Thanks for your time and knowledge.

CREATE OR REPLACE
TYPE MYTABLETYPE
AS TABLE OF NUMBER(15,0)
/

CREATE OR REPLACE
FUNCTION STR2TBL (
P_STR IN VARCHAR2
)
RETURN MYTABLETYPE AS
L_STR LONG DEFAULT P_STR || ',';
L_N NUMBER;
L_DATA MYTABLETYPE := MYTABLETYPE ();
V_ID NUMBER;
BEGIN
LOOP
L_N := INSTR (L_STR, ',');
EXIT WHEN (NVL (L_N, 0) = 0);
V_ID := NVL (LTRIM (RTRIM (
SUBSTR (L_STR, 1, L_N - 1))), -9999999999);

IF V_ID != -9999999999 THEN
L_DATA.EXTEND;
L_DATA (L_DATA.COUNT) := V_ID;
END IF;

L_STR := SUBSTR (L_STR, L_N + 1);
END LOOP;

RETURN L_DATA;
END;
/

CREATE TABLE T AS (
SELECT
OBJECT_ID + 100000 CNA_ID,
OBJECT_NAME,
OBJECT_TYPE,
0 DELETED,
OBJECT_ID ASSOC_ID1,
0 ASSOC_ID2,
0 ASSOC_ID3
FROM ALL_OBJECTS
UNION
SELECT
OBJECT_ID + 200000 CNA_ID,
OBJECT_NAME,
OBJECT_TYPE,
1 DELETED,
0 ASSOC_ID1,
OBJECT_ID ASSOC_ID2,
0 ASSOC_ID3
FROM ALL_OBJECTS
UNION
SELECT
OBJECT_ID + 300000 CNA_ID,
OBJECT_NAME,
OBJECT_TYPE,
0 DELETED,
0 ASSOC_ID1,
0 ASSOC_ID2,
OBJECT_ID ASSOC_ID3
FROM ALL_OBJECTS
UNION
SELECT
OBJECT_ID + 400000 CNA_ID,
OBJECT_NAME,
OBJECT_TYPE,
0 DELETED,
OBJECT_ID ASSOC_ID1,
OBJECT_ID ASSOC_ID2,
0 ASSOC_ID3
FROM ALL_OBJECTS
UNION
SELECT
OBJECT_ID + 500000 CNA_ID,
OBJECT_NAME,
OBJECT_TYPE,
1 DELETED,
OBJECT_ID ASSOC_ID1,
0 ASSOC_ID2,
OBJECT_ID ASSOC_ID3
FROM ALL_OBJECTS
UNION
SELECT
OBJECT_ID + 600000 CNA_ID,
OBJECT_NAME,
OBJECT_TYPE,
0 DELETED,
OBJECT_ID ASSOC_ID1,
OBJECT_ID ASSOC_ID2,
OBJECT_ID ASSOC_ID3
FROM ALL_OBJECTS);


CREATE INDEX AK_T_ASSOC ON T
(
ASSOC_ID1 ASC,
ASSOC_ID2 ASC,
ASSOC_ID3 ASC,
DELETED ASC
)
/


ALTER TABLE T
ADD CONSTRAINT PK_T PRIMARY KEY (CNA_ID)
USING INDEX
/

analyze table t compute statistics;

SET AUTOTRACE ON

SELECT CNA_ID, OBJECT_NAME, OBJECT_TYPE
FROM T
WHERE DELETED = 0
AND ASSOC_ID1 IN (0,4525, 420, 81644)
AND ASSOC_ID2 IN (0,4525, 420, 81644)
AND ASSOC_ID3 IN (0,4525, 420, 81644)
GROUP BY CNA_ID, OBJECT_NAME, OBJECT_TYPE
HAVING COUNT (1) > (0)
ORDER BY 3;


SELECT CNA_ID, OBJECT_NAME, OBJECT_TYPE
FROM T
WHERE DELETED = 0
AND ASSOC_ID1 IN (SELECT * FROM THE (SELECT CAST
(STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
FROM DUAL))
AND ASSOC_ID2 IN (SELECT * FROM THE (SELECT CAST
(STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
FROM DUAL))
AND ASSOC_ID3 IN (SELECT * FROM THE (SELECT CAST
(STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
FROM DUAL))
GROUP BY CNA_ID, OBJECT_NAME, OBJECT_TYPE
HAVING COUNT (1) > (0)
ORDER BY 3;


SELECT /*+ FIRST_ROWS */
CNA_ID, OBJECT_NAME, OBJECT_TYPE
FROM T
WHERE DELETED = 0
AND ASSOC_ID1 IN (SELECT * FROM THE (SELECT CAST
(STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
FROM DUAL) where rownum >= 0)
AND ASSOC_ID2 IN (SELECT * FROM THE (SELECT CAST
(STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
FROM DUAL) where rownum >= 0)
AND ASSOC_ID3 IN (SELECT * FROM THE (SELECT CAST
(STR2TBL ('0,4525, 420, 81644') AS MYTABLETYPE)
FROM DUAL) where rownum >= 0)
GROUP BY CNA_ID, OBJECT_NAME, OBJECT_TYPE
HAVING COUNT (1) > (0)
ORDER BY 3;


multiple column subquery

umesh, August 28, 2003 - 5:26 am UTC

Tom
Extremely Sorry for asking this silly thing here
I am involved in migration of database from sqlserver to Oracle and I caught one of the queries in SQL server wrong and I dont know whom do i contact

In Oracle I would have simply written
select * from emp where
( empno,deptno) in ( select empno,deptno from emp_1) ;

Any help can I get in converting this to SQL server
becoz the view they have is based on this query;

Tom Kyte
August 28, 2003 - 7:49 am UTC


guess sql server isn't as "sql-9x" as the say....

use a where exists if they don't support that construct


where exists ( select null from emp_1 where emp_1.empno = emp.empno and emp_1.deptno = emp.deptno )


clob instead of varchar2 in list

Sandeep, September 17, 2003 - 2:48 pm UTC

I was going to change your procedure to accept clob instead of varchar2...
I need Pstring to be more than 4000 characters...hence I thought about clobs..
I changed it as follows and got errors...can this be done..if yes...how?
Thanks... and clob parameter will go to 32k right?:



create or replace
function in_list( p_string in clob ) return myTableType
as
l_string clob default p_string || ',';
l_data myTableType := myTableType;
n number;
begin
loop
exit when l_string is null;
n := instr( l_string, ',' );
l_data.extend;
l_data(l_data.count) :=
ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
l_string := substr( l_string, n+1 );
end loop;

return l_data;
end;
/

Function created.



SQLWKS> create or replace
2> function in_list( p_string in clob ) return myTableType
3> as
4> l_string clob default p_string || ',';
5> l_data myTableType := myTableType;
6> n number;
7> begin
8> loop
9> exit when l_string is null;
10> n := instr( l_string, ',' );
11> l_data.extend;
12> l_data(l_data.count) :=
13> ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
14> l_string := substr( l_string, n+1 );
15> end loop;
16>
17> return l_data;
18> end;
19> /




LINE/COL ERROR
-------- -----------------------------------------------------------------
3/23 PL/SQL: Item ignored
3/36 PLS-00306: wrong number or types of arguments in call to '||'
8/9 PL/SQL: Statement ignored
8/19 PLS-00320: the declaration of the type of this expression is
incomplete or malformed

9/9 PL/SQL: Statement ignored
9/21 PLS-00320: the declaration of the type of this expression is
incomplete or malformed

11/9 PL/SQL: Statement ignored
12/37 PLS-00320: the declaration of the type of this expression is
incomplete or malformed

13/9 PLS-00320: the declaration of the type of this expression is
incomplete or malformed

13/9 PL/SQL: Statement ignored


Tom Kyte
September 17, 2003 - 5:38 pm UTC

until 9ir2, you have to use the dbms_lob package to add stuff to the end of a lob like that.


if you have such a seriously big inlist -- i would suggest you do not use this technique but consider loading the stuff into a global temporary table using bulk inserts and then query "where in (select * from gtt)"

it'll be bothersome to use a clob for this.

CLOB in list

Sandeep, September 17, 2003 - 2:56 pm UTC

Database version is 8.1.7.4

Thanks.

no rows selected

Bayo, October 07, 2003 - 9:54 am UTC

Thanks for the trick. I've tried your example using the all_users table, but when I try to use one of my own tables, the result is always no rows selected.
see what I did below.


create or replace type myTableType as table of varchar2 (255);

/
create or replace
function in_list( p_string in varchar2 ) return myTableType
as
l_string long default p_string || ',';
l_data myTableType := myTableType();
n number;
begin
loop
exit when l_string is null;
n := instr( l_string, ',' );
l_data.extend;
l_data(l_data.count) := ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
l_string := substr( l_string, n+1 );
end loop;

return l_data;
end;
/


select * from all_users where username in ( select * from THE ( select cast( in_list('OPS$TKYTE, SYS, SYSTEM') as mytableType ) from dual ) );

The result for the above selected stsement is:

USERNAME USER_ID CREATED
------------------------------ ---------- ---------
SYS 0 20-MAY-99
SYSTEM 5 20-MAY-99

Here is a select statement using on of my own table.
select * from CSHPTDETAILS where CASHPOINTCODE in ( select * from THE ( select cast( in_list('1,1ABC,TCD') as myTableType ) from dual ) );


The result for the above query is:
no rows selected

This is despite the fact that I have data with 1,1ABC,TCD as cashpointcode in the CSHPTDETAILS table..

Many Thanks for your anticipated help.



Tom Kyte
October 07, 2003 - 10:08 am UTC

one needs a FULL test case to get any sort of meaningful feedback.  For example -- I'll post two -- one that "works" and one that "works differently but looks like your example" (eg: both work -- do what they are supposed to)



ops$tkyte@ORA920> drop table CSHPTDETAILS;
 
Table dropped.
 
ops$tkyte@ORA920> create table CSHPTDETAILS ( cashpointcode varchar2(20) );
 
Table created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( '1' );
 
1 row created.
 
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( '1ABC' );
 
1 row created.
 
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( 'TCD' );
 
1 row created.
 
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( 'Hello World' );
 
1 row created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> select * from CSHPTDETAILS where CASHPOINTCODE in ( select * from THE ( select
  2  cast( in_list('1,1ABC,TCD')  as myTableType ) from dual ) );
 
CASHPOINTCODE
--------------------
1
1ABC
TCD
 
<b>that shows, this "works", but how to make it "work" like yours?  I'll guess -- you are using a 'CHAR' datatype (bad idea if you are)</b>


ops$tkyte@ORA920>
ops$tkyte@ORA920>
ops$tkyte@ORA920> drop table CSHPTDETAILS;
 
Table dropped.
 
ops$tkyte@ORA920> create table CSHPTDETAILS ( cashpointcode char(20) );
 
Table created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( '1' );
 
1 row created.
 
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( '1ABC' );
 
1 row created.
 
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( 'TCD' );
 
1 row created.
 
ops$tkyte@ORA920> insert into CSHPTDETAILS values ( 'Hello World' );
 
1 row created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> select * from CSHPTDETAILS where CASHPOINTCODE in ( select * from THE ( select
  2  cast( in_list('1,1ABC,TCD')  as myTableType ) from dual ) );
 
no rows selected
 


<b>when you compare the char to the varchar2 -- they do not compare since the varchar2 doesn't have the trailing blanks (that just waste space in your database and cause all kinds of heartburn like this)</b>



Just a guess -- for since I don't have a full test case, thats the best I can do. 

no rows selected

bayo, October 07, 2003 - 10:31 am UTC

Thanks Tom,

Yes I'm using 'CHAR' datatype. This is a legacy system, and I'm not allowed to start changing the datatype.

But is there any way of getting row returned if 'CHAR' data type is used.

Or is there any other method that works with both Varchar2 and CHAR datatypes.

Many Thanks for your help.

Tom Kyte
October 07, 2003 - 10:49 am UTC

just rpad out the column_value column the nested table type returns to be the same length as your database column

ops$tkyte@ORA920> select *
  2    from CSHPTDETAILS
  3   where CASHPOINTCODE in ( select rpad(column_value,20)
  4                from TABLE( cast( in_list('1,1ABC,TCD')  as myTableType )  )
  5                          )
  6  /
 
CASHPOINTCODE
--------------------
1
1ABC
TCD
 

no rows selected

Bayo, October 08, 2003 - 4:38 am UTC

Thanks Tom,

I got the following error when I rpad out the column_value column to return
the same length as my database column.


SP2-0642: SQL*Plus internal error state 2133, context 0:0:0
Unsafe to proceed
SP2-0642: SQL*Plus internal error state 2133, context 0:0:0
Unsafe to proceed


I think the problem may have something to do with the fact that my table has more than one column.


Anyway, I've got it working by using CHAR instead of VARCHAR2.

This is what I did.

create or replace type myTableType as table of CHAR (3000);
/
create or replace
function in_list( p_string in CHAR ) return myTableType
as
l_string long default p_string || ',';
l_data myTableType := myTableType();
n number;
begin
loop
exit when l_string is null;
n := instr( l_string, ',' );
l_data.extend;
l_data(l_data.count) := ltrim( rtrim( substr( l_string, 1, n-1 ) ) ) ;
l_string := substr( l_string, n+1 );
end loop;

return l_data;
end;
/
Thanks very much for your help.





Optimizer problems with variable in-list

Mark Manning, October 19, 2003 - 7:29 am UTC

With regards to the problem Rick from NC listed, here is an
alternative. Try rewriting the inlist into a inline view and
join it back to the table. The situtation is rare, however,
I have encountered my index range scans becoming full table scans.

Here is my example:

CREATE TABLE INLIST_TEST NOLOGGING AS SELECT * FROM DBA_OBJECTS
/

BEGIN
FOR I IN 1 .. 67
LOOP
INSERT INTO INLIST_TEST
SELECT * FROM DBA_OBJECTS;
END LOOP;
COMMIT;
/

CREATE INDEX X_INLIST_TEST_N01 ON INLIST_TEST (OBJECT_ID)
NOLOGGING COMPUTE STATISTICS
/

ANALYZE TABLE INLIST_TEST COMPUTE STATISTICS
FOR TABLE FOR ALL INDEXED COLUMNS
/


My original SQL statement:

SELECT COUNT(*) FROM INLIST_TEST X
WHERE X.OBJECT_ID IN (1,2,3,4,5)

SELECT STATEMENT OPTIMIZER MODE=CHOOSE Rows=1 Cost=4
SORT AGGREGATE
INLIST ITERATOR
INDEX RANGE SCAN X_INLIST_TEST_N01

Returns in less than 1 second.

Implement dynamic in-list and run.

SELECT COUNT(*) FROM INLIST_TEST X
WHERE X.OBJECT_ID IN
(SELECT * FROM TABLE(CAST(CONVERT_INLIST('1,2,3,4,5') AS MY_NUM_TYPE)))

SELECT STATEMENT OPTIMIZER MODE=CHOOSE Rows=1 Cost=11 M
SORT AGGREGATE
NESTED LOOPS SEMI
TABLE ACCESS FULL INLIST_TEST
COLLECTION ITERATOR PICKLER FETCH CONVERT_INLIST

Returns in 30 seconds.

Ok. Lets force index usage.

SELECT /*+ INDEX(X) */ COUNT(*) FROM INLIST_TEST X
WHERE X.OBJECT_ID IN
(SELECT * FROM TABLE(CAST(CONVERT_INLIST('1,2,3,4,5') AS MY_NUM_TYPE)))

SELECT STATEMENT OPTIMIZER MODE=CHOOSE Rows=1 Cost=12 M
SORT AGGREGATE
NESTED LOOPS SEMI
INDEX FAST FULL SCAN X_INLIST_TEST_N01
COLLECTION ITERATOR PICKLER FETCH CONVERT_INLIST

Returns in 27 seconds.

Rewrite variable in-list into a inline view.

SELECT COUNT(*) FROM INLIST_TEST X,
(SELECT COLUMN_VALUE AS OBJ_ID FROM TABLE(CAST(CONVERT_INLIST('1,2,3,4,5') AS MY_NUM_TYPE))) Y
WHERE X.OBJECT_ID = Y.OBJ_ID

SELECT STATEMENT OPTIMIZER MODE=CHOOSE Rows=1 Cost=792
SORT AGGREGATE
HASH JOIN
COLLECTION ITERATOR PICKLER FETCH CONVERT_INLIST
INDEX FAST FULL SCAN X_INLIST_TEST_N01

Returns in 3 seconds.

Force index usage with inline view.

SELECT /*+ INDEX(X) */ COUNT(*) FROM INLIST_TEST X,
(SELECT COLUMN_VALUE AS OBJ_ID FROM TABLE(CAST(CONVERT_INLIST('1,2,3,4,5') AS MY_NUM_TYPE))) Y
WHERE X.OBJECT_ID = Y.OBJ_ID

SELECT STATEMENT OPTIMIZER MODE=CHOOSE Rows=1 Cost=8149
SORT AGGREGATE
NESTED LOOPS
COLLECTION ITERATOR PICKLER FETCH CONVERT_INLIST
INDEX RANGE SCAN X_INLIST_TEST_N01

Returns in less than 1 second.

error sp2-0642......

Anurag, December 09, 2003 - 12:41 am UTC

Dear Tom,

You've been always giving a right solution to our problem. I am having a testing Oracle 8i and Oracle 9i both installed on same machine with winxp. I tried to install D2k ver 6.0 . Now starting with sql*plus it pops a message "???.msb error" . I tried to uninstall and removed D2k entries from registry. Now while starting SQL*PLUS of 8i/9i it displays sp2-0642:sql*plus internal error 2167, context 4294967294:2:0 unable to proceed.

What to do??? pl. Help.


Tom Kyte
December 09, 2003 - 6:25 am UTC

sounds like your oracle home is set wrong

use the oracle home selector tool from the start menu.

TNS error

Anurag, December 10, 2003 - 9:45 am UTC

Yes, After setting OracleHome, it says
Ora-12560 TNS Protocol Adapter error

May be the protocols are over-written by older ver.??

Do the needful.

Regards,

Anurag



Tom Kyte
December 10, 2003 - 3:40 pm UTC

please contact support -- i don't use windows -- there is some configuration issue here -- they are excellent at helping with that.

(could be that the database isn't even started, you'll get that trying to connect locally to a "not up" database on windows as I recall from the distant past)

Is there a simple way to get distinct values from the array?

Meyer, December 11, 2003 - 2:17 pm UTC

I read above (and a few others) and want to make sure I am going to take the correct aproach....in 9Ir2 I am doing this...

declare
l_vc_arr2 wwv_flow_global.vc_arr2;
begin

l_vc_arr2 := WWV_FLOW_UTILITIES.STRING_TO_TABLE(l_the_colon_delim_string);

FOR z IN 1..l_vc_arr2.count LOOP

---processing here, only want to do once for each UNIQUE value instead of each individual value as there can be duplicates in the array.

end loop;
end;

The array typically contains 1-10 email addresses (that started in the colon delim list) but can contain duplicates in that set (due to logic I introduced but want to keep), is there a simple way to select a distinct set from the array for processing?

Thanks,
Meyer

Tom Kyte
December 11, 2003 - 2:39 pm UTC

well, if you use a SQL TYPE, you can use my in_list logic and "select distinct" from it.

haven't really seen which would be faster for 1..10 elements tho. might be 6 one way, 1/2 dozen the other.

Very Useful

Sami, December 24, 2003 - 3:13 pm UTC


Excellent, but.....

Bruno Paquet, February 09, 2004 - 3:16 pm UTC

Hi Mr Kyte,

I'm using this trick on a customer, on 8.1.7.0.0. and the table just get about 3 rows, but we modify the string very often. We are experiencing some performance problem, now. When i'm using a tool to see what is happening, the SELECT showing is allways the one on the view (because i created a view, like your exemple). Could you have an idea on what i going on : There are 4 active users at a time, and we reference the view quite often.

dummy rowid ?

robert, February 09, 2004 - 8:34 pm UTC

Tom, 

SQL> desc tblctsearchresult
Name            Type           Nullable  
--------------- -------------- -------- 
USERSEQ         NUMBER                                   
CLIENTLISTROWID ROWID          Y                         
DATESTAMP       DATE                                     
USERID          VARCHAR2(30)   Y                         
USERDATA1       VARCHAR2(2000) Y   

This is used to store ROWID of web page search results...
I have to add column USERDATA1 and make CLIENTLISTROWID
NULLABLE because I need to store some extra info related to this search.

So is there a "valid" dummy ROWID I can use to avoid -ORA-01410 Invalid ROWID- and put into this column for these extra info rows ?
Or if I leave the NULLS in that column, am I gonna have a problem when doing a lookup on this column, like:

SELECT * FROM v_clientlist WHERE ROWID IN SELECT clientlistrowid  FROM tblctsearchresult

'cause I read here about possible problem with either IN or NOT IN where there are NULLS...

Thanks 

Tom Kyte
February 09, 2004 - 8:53 pm UTC

Just use NULL, it'll be OK.

it would be a NOT IN that would cause problems and then you just use

where not in ( select ... where something IS NOT NULL )

to fix that right up.

varchar inlist

Sha, February 27, 2004 - 10:59 am UTC

Hi Tom,
I read your solution for INlist and the example you gave

variable x varchar2(255)
define x="1,2,3,4,5"
exec :x := '&X'
select * from t where object_id in ( &X );
old 1: select * from t where object_id in ( &X )
new 1: select * from t where object_id in ( 1,2,3,4,5 )

This works great for Number List.

I need to implement for CHAR list e.g.
output should be
old 1: select * from t where object_id in ( &X )
new 1: select * from t where object_id in ( '1','2','3','4','5' )

Thanks in advance,
Regards,
Sha

Tom Kyte
February 27, 2004 - 2:29 pm UTC

i would not suggest using literals. use str2table as demonstrated (it is a table of number or a table of varchar2's whatever you want it to be a table of)

Indexes break

Sha, February 27, 2004 - 3:17 pm UTC

Hi Tom,
I was doing exactly that but my Indexes do not work if I use select cast..
I was surprise to see how indexes work in your example.
I converted all the dynamic IN queries to use select cast and now I realize that in all SQL's our indexes are broken.
a) I tried where rownum > 0 it does not help
b) I tried /*+ first_rows */ hint , it does not work.

1) is the only option to use cursor sharing = force with the dynamic queries, but again you say thats bad way of writing SQL.
2) Why does your SQL use index with select cast... In my case I may have more that one select cast condition in where clause. Is it that by chance your SQl uses indexes or I am doing something wrong.
3) Is the number of joins causing this.
Can you show an example of with 4 tables , multiple joins and use 2 select cast in where clause. I want to see how your query will use Indexes.

I am new to oracle, I read your web-site alot. Thanks for helping me.

Thanks in advance
Sha

Tom Kyte
February 27, 2004 - 4:32 pm UTC

the indexes are not "broken". there are two things to look at

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:3779680732446#15740265481549 <code>

and the use of a gtt to stash the values instead of a collection.



moving sql into database

dwl, March 05, 2004 - 7:22 am UTC

Tom

(Bear with me this does have relevance to refcursors!)

I am attempting to move the sql from the java pages into the database, as i believe this is the best place for it. A couple of questions i have though are

1) For ad hoc sql i can create stored procedures using ref cursors and sys_contexts in order to create dynamic WHERE clauses as determined by what the client passes in, using your methods of a variable IN list etc. However do i need to create a separate stored procedure for every simple sql statement that selects from a different table?? Or can i also BIND the tablename at runtime and still only hard parse once?

eg

PROCEDURE P1 ( P_1 IN VARCHAR2 DEFAULT NULL,
P_Cur IN OUT C_Return_Cursor )


IS

l_query varchar2(32000)
default 'SELECT * from t1 where 1=1';

BEGIN

IF ( P_1 IS NOT NULL ) THEN

DBMS_SESSION.SET_CONTEXT( 'MY_CTX', 'P1_STRING', P_1);
l_query := l_query ||' AND c1 IN ( SELECT *
FROM THE ( SELECT CAST( str2tbl( sys_context( ''MY_CTX'', ''P1_STRING'' ) ) as tbl_Numbers ) from dual ) ) ';

END IF;

open P_Cur for l_query;



END P1 ;




PROCEDURE P2 ( P_1 IN VARCHAR2 DEFAULT NULL,
P_Cur IN OUT C_Return_Cursor )


IS

l_query varchar2(32000)
default 'SELECT * from t2 where 1=1';

BEGIN

IF ( P_1 IS NOT NULL ) THEN

DBMS_SESSION.SET_CONTEXT( 'MY_CTX', 'P2_STRING', P_1);
l_query := l_query ||' AND c1 IN ( SELECT *
FROM THE ( SELECT CAST( str2tbl( sys_context( ''MY_CTX'', ''P2_STRING'' ) ) as tbl_Numbers ) from dual ) ) ';

END IF;

open P_Cur for l_query;



END P2 ;



Could i replace these 2 with :

PROCEDURE P3 ( P_1 IN VARCHAR2 DEFAULT NULL,
P_Table_name IN VARCHAR2,
P_Cur IN OUT C_Return_Cursor )


IS

l_query varchar2(32000)
default 'SELECT * from '||P_Table_name||' where 1=1';

BEGIN

IF ( P_1 IS NOT NULL ) THEN

DBMS_SESSION.SET_CONTEXT( 'MY_CTX', 'P3_STRING', P_1);
l_query := l_query ||' AND c1 IN ( SELECT *
FROM THE ( SELECT CAST( str2tbl( sys_context( ''MY_CTX'', ''P3_STRING'' ) ) as tbl_Numbers ) from dual ) ) ';

END IF;

open P_Cur for l_query;



END P3 ;


So would P3 still use bind variable?? Is this the best method to use for a generic simple procedure for sql from different tables?


2) In the above procedures is there any performance issue (or any other issue)with using 'SELECT * FROM..' as opposed to selecting all field names from the table?

3) How should i best deal with INSERTS and UPDATES, storing the sql in the database?
Maybe try and create a generic procedure using eg varrays and objects to pass in the parameters to insert or update?

Or just create individual procedures for each insert or update sql i require to run that exists in the application??

Thanks for your help.



Tom Kyte
March 05, 2004 - 8:44 am UTC

1) you'll hard parse ONCE for each table you put in there (have to, they have different plans!!)

You only need a single procedure.
You would concatenate the tablename in.
It'll hard parse as little as possible -- but at least once per tablename used!


2) yes, definitely. first there is just the overhead of moving EVERY column from server to client. second there is the change in access plans that can and will occurr. consider:

big_table@ORA9IR2> select owner, object_type, object_id from big_table;

1000000 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=403 Card=999620 Bytes=19992400)
1 0 INDEX (FAST FULL SCAN) OF 'BIG_TABLE_IDX1' (NON-UNIQUE) (Cost=403 Card=999620 Bytes=19992400)

big_table@ORA9IR2> select * from big_table;

1000000 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=1379 Card=999620 Bytes=99962000)
1 0 TABLE ACCESS (FULL) OF 'BIG_TABLE' (Cost=1379 Card=999620 Bytes=99962000)


You can skip hitting the table many times (just using indexes). but if you select * -- tables will be in there.


(this is why you cannot just take a query "X" and

select count(*) from ( "X" )

to 'tune' it. the optimizer sees "no columns needed, lets skip base table accesses and such" )


3) don't think of it as inserts and updates. think of it as transactions.

You would create a procedure to do "transaction x"

"transaction x" has a set of inputs.

You would use collections (maybe -- plsql table types are perhaps the easiest to deal with) and scalars (for sure), but I would not use object types. unless you went hole hog with JPUB and let that generate the code.




Eliminate dynamic sql for in list

Jennifer Chen, March 05, 2004 - 2:39 pm UTC

Hi Tom,

I have a stored procedure accepts a list of mpi_number and returns values to the c++ code. The table contains 1776518 rows and took about 3 seconds to finish. Do you have a better way to accomplish this? I tried your inlist function, but seems take longer...

PROCEDURE get_cchperson_by_mpilist (
p_mpi_list IN VARCHAR2,
p_refcursor OUT sys_refcursor
)
AS
BEGIN
IF p_mpi_list IS NULL
THEN
raise_application_error (-20000, 'MPINumber List is Required');
END IF;

OPEN p_refcursor
FOR 'SELECT pid_number,
mpi_number,
afis_county_code,
afis_flag,
afis_rfi,
consol_sid,
dna_flag,
domestic_assault_counter,
domestic_assault_flag,
domestic_violence_flag,
TO_CHAR(enter_date_time, ''MM/DD/YYYY HH24:MI''),
enter_user_id,
update_user_id
FROM alias.cch_person
WHERE mpi_number in ('
|| p_mpi_list
|| ') ORDER BY mpi_number';
END get_cchperson_by_mpilist;


BEGIN GET_CCHPERSON_BY_MPILIST( '109080,329729,402969,
465198,543705,559773,738160,758460,925904',:P_REFCURSOR ); END;


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 2.23 2.27 0 0 0 1
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 2.23 2.27 0 0 0 1

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 66

select * from cch_person where pid_number in
( select *
from TABLE ( select cast( in_list('109080,329729,402969,465198,543705,559773,738160,758460,925904')
as a_mpi_number ) from dual ) );

9 rows selected.

Elapsed: 00:00:43.02

I don't have an index for your code. Oracle seems use index range scan on mpi_number for my sp.

Thanks in advance for your time and help.

Thank You

A reader, March 05, 2004 - 4:04 pm UTC

Hi Tom,

Your solution has been proved faster. The note is incrediable helpful.

Thank you, thank you, thank you!!!

alter session set sql_trace=true


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: 61
********************************************************************************

select * from cch_person where pid_number in
( select /*+ cardinality(t 10 ) */ *
from TABLE ( select cast( in_list('109080,329729,402969,465198,543705,559773,738160,758460,925904')
as a_mpi_number ) from dual ) t )

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.01 0 7 0 0
Execute 1 0.00 0.00 0 6 0 0
Fetch 2 0.00 0.00 0 29 0 9
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.00 0.01 0 42 0 9

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
9 NESTED LOOPS (cr=29 r=0 w=0 time=820 us)
9 VIEW (cr=0 r=0 w=0 time=224 us)
9 SORT UNIQUE (cr=0 r=0 w=0 time=193 us)
9 COLLECTION ITERATOR PICKLER FETCH (cr=0 r=0 w=0 time=25 us)
9 TABLE ACCESS BY INDEX ROWID CCH_PERSON (cr=29 r=0 w=0 time=464 us)
9 INDEX UNIQUE SCAN PK_CCH_PERSON (cr=20 r=0 w=0 time=242 us)(object id 34060)

********************************************************************************

BEGIN CRIMINAL_HISTORY_PKG.GET_CCHPERSON_BY_MPILIST( '109080,329729,402969,
465198,543705,559773,738160,758460,925904',:c ); END;


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 2 0
Execute 1 0.35 0.37 0 0 2 1
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.35 0.37 0 0 4 1

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61
********************************************************************************

SELECT pid_number,
mpi_number,
afis_county_code,
afis_flag,
afis_rfi,
consol_sid,
dna_flag,
domestic_assault_counter,
domestic_assault_flag,
domestic_violence_flag,
TO_CHAR(enter_date_time, 'MM/DD/YYYY HH24:MI'),
enter_user_id,
TO_CHAR(expunge_date_time, 'MM/DD/YYYY HH24:MI'),
expunge_reason,
expunge_user_id,
fbi,
hyta_counter,
hyta_flag,
iffs,
iffs_disqual_counter,
iffs_poss_disqual_counter,
iii_status,
TO_CHAR(iii_update_date, 'MM/DD/YYYY'),
identifying_comments,
image_flag,
n7411_counter,
n7411_flag,
off_safety_flag,
pob,
prn,
palm_flag,
parent_kidnapping_counter,
parent_kidnapping_flag,
TO_CHAR(rights_restore_date, 'MM/DD/YYYY'),
rights_restore_flag,
rights_restore_ori,
sid,
suppressed_flag,
set_aside_flag,
status_code,
TO_CHAR(update_date_time, 'MM/DD/YYYY HH24:MI'),
update_user_id
FROM alias.cch_person
WHERE mpi_number in (109080,329729,402969,465198,543705,559773,738160,758460,925904) ORDER BY mpi_number

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 2 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 0.00 0.00 0 36 0 9
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 0.00 0.00 0 36 2 9

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61 (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
9 INLIST ITERATOR (cr=36 r=0 w=0 time=619 us)
9 TABLE ACCESS BY INDEX ROWID OBJ#(33948) (cr=36 r=0 w=0 time=508 us)
9 INDEX RANGE SCAN OBJ#(35197) (cr=27 r=0 w=0 time=325 us)(object id 35197)




********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.01 0 7 2 0
Execute 3 0.35 0.37 0 6 2 1
Fetch 2 0.00 0.00 0 29 0 9
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 7 0.35 0.39 0 42 4 10

Misses in library cache during parse: 2
Misses in library cache during execute: 1


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 2 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 0.00 0.00 0 36 0 9
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 0.00 0.00 0 36 2 9

Misses in library cache during parse: 1

4 user SQL statements in session.
0 internal SQL statements in session.
4 SQL statements in session.
********************************************************************************
Trace file: aliasdev_ora_3044.trc
Trace file compatibility: 9.00.01
Sort options: default

1 session in tracefile.
4 user SQL statements in trace file.
0 internal SQL statements in trace file.
4 SQL statements in trace file.
4 unique SQL statements in trace file.
105 lines in trace file.



generic procedure

dwl, March 08, 2004 - 9:18 am UTC

Tom

thanks for the reply.
Just going back to the generic procedure approach for adhoc sql. Exactly how generic would you make the procedure??

I mean do you recommend a generic one for just simple adhoc sql like

select .. .. .. from table1;

and then have individual procedures for anything more complicated?
What about another generic one for simple joins?

What about order by, maybe you could have an in ARRAY for
the order by elements?

What about DISTINCT, would you use an IN parameter concatenated in?


Do all these conditions require separate procedures or should you just build ONE procedure for your application which can run all the sql you require, no matter how complicated?? ie lots of IF statements?

I can think of several ways of doing all of this type of stuff but I am really looking for your recommendation or best practice.

Many thanks

Tom Kyte
March 08, 2004 - 1:38 pm UTC

hard to say in general, you'll have to use your design sense to figure out "one" or "many"

array's can apply -- easy to pass a flexible number of arguments....

distinct would have to be concatenated in if optional, yes.


I find a procedure "per problem" is what I send up with -- you need to define "problem" here :)

Eliminate sort in this query

Jennifer Chen, March 08, 2004 - 11:37 am UTC

Hi Tom,

Is there a way to eliminate the two sorts in this query. I tried to add hit /*+ INDEX_FFS (name_rac pk_name_rac) */, but the sorts are still there (mpi_number is the PK of name_rac). Can you please help?

Thank you.

SQL> SELECT mpi_number, rac, primary_value_flag
  2    FROM alias.name_rac
  3   WHERE mpi_number IN (
  4         SELECT /*+ CARDINALITY(t 10 ) */
  5                *
  6           FROM TABLE
  7                (CAST
  8                    (MASTERINDEX_PKG.GET_MPILIST (:in_list) AS a_mpi_number
  9                    )
 10                ) t
 11                WHERE ROWNUM >= 0)
 12   ORDER BY mpi_number;

no rows selected

Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=34 Card=10 Bytes=220
          )

   1    0   SORT (ORDER BY) (Cost=34 Card=10 Bytes=220)
   2    1     NESTED LOOPS (Cost=33 Card=10 Bytes=220)
   3    2       VIEW OF 'VW_NSO_1' (Cost=11 Card=10 Bytes=130)
   4    3         SORT (UNIQUE)
   5    4           COUNT
   6    5             FILTER
   7    6               COLLECTION ITERATOR (PICKLER FETCH) OF 'GET_MP
          ILIST'

   8    2       TABLE ACCESS (BY INDEX ROWID) OF 'NAME_RAC' (Cost=2 Ca
          rd=1 Bytes=9)

   9    8         INDEX (UNIQUE SCAN) OF 'PK_NAME_RAC' (UNIQUE) (Cost=
          1 Card=1)





Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          6  consistent gets
          0  physical reads
          0  redo size
        343  bytes sent via SQL*Net to client
        368  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
          0  rows processed 

Tom Kyte
March 08, 2004 - 2:19 pm UTC

while you and i can see the secondary sort isn't technically necessary, the optimizer is not seeing that and I could not make it see that.

ORA-06502 error

Arun Mathur, March 18, 2004 - 5:37 pm UTC

Tom,

I'm getting a

ORA-06502: PL/SQL: numeric or value error: character string buffer too small

error when the argument I pass into in_list exceeds a certain length. Do you have any thoughts?

Thanks again.
Arun

Tom Kyte
March 18, 2004 - 6:08 pm UTC

thoughts -- you need to debug it a little to see which buffer it is having an issue with?

the code is about as simple and small as you get -- please, take a minute to take a look see.



Thanks

Arun Mathur, March 18, 2004 - 10:05 pm UTC

Once again, it would have helped if I actually took a second to read the error message. My apologies, Tom. On a plus note, look forward to seeing you at the Atlanta OUG next week.

Arun


this approach in a view ?

A reader, March 24, 2004 - 7:19 am UTC

I'm having a problem with this approach in a view when I try to make the view available to another schema:
Test scenario:


SQL> create or replace function fInlistIterator( p_string in varchar2 ) return str_array
  2      as
  3          l_string        long default p_string || ',';
  4          l_data          str_array := str_array();
  5          n               number;
  6      begin
  7        loop
  8            exit when l_string is null;
  9            n := instr( l_string, ',' );
 10           l_data.extend;
 11           l_data(l_data.count) := 
 12                   ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
 13           l_string := substr( l_string, n+1 );
 14      end loop;
 15  
 16      return l_data;
 17    end;
 18  /

Function created.

SQL> 
SQL> 
SQL> create or replace view EuropeanCountries as
  2  SELECT * FROM country
  3  WHERE countryid IN 
  4  (SELECT * FROM 
  5    THE(SELECT CAST(fInlistIterator(rulevalue) as str_array)
  6   FROM rule WHERE ruleid = 63 ));

View created.

SQL> create or replace public synonym EuropeanCountries for EuropeanCountries;

Synonym created.

SQL> create or replace public synonym fInlistIterator for fInlistIterator;

Synonym created.

SQL> 
SQL> GRANT ALL ON fInlistIterator TO OTHER_USER;

Grant succeeded.

SQL> GRANT ALL ON EuropeanCountries TO OTHER_USER;

Grant succeeded.

SQL> 
SQL> CONNECT OTHER_USER/...
Connected.
SQL> 
SQL> 
SQL> SELECT * from EuropeanCountries;
SELECT * from EuropeanCountries
              *
ERROR at line 1:
ORA-01031: insufficient privileges












 

Tom Kyte
March 24, 2004 - 9:27 am UTC

no version?

in 9ir2, all other user needs is "grant select on view"

in 8i, it appears they need execute on the TYPE str_array and the view.

view issue

A reader, March 24, 2004 - 11:34 am UTC

Sorry, it's 9iR2 and still not working !

SQL> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle9i Enterprise Edition Release 9.2.0.2.1 - Production
PL/SQL Release 9.2.0.2.1 - Production
CORE    9.2.0.2.0       Production
TNS for 32-bit Windows: Version 9.2.0.2.0 - Production
NLSRTL Version 9.2.0.2.0 - Production 

Tom Kyte
March 24, 2004 - 1:17 pm UTC

give me the entire example, like this, from start to finish that demonstrates this issue:

ops$tkyte@ORA9IR2> create or replace type tabType as table of number
  2  /
 
Type created.
 
ops$tkyte@ORA9IR2> create or replace function f( p_string in varchar2 ) return tabType
  2  as
  3          l_data tabType := tabType( 1,2,3 );
  4  begin
  5          return l_data;
  6  end;
  7  /
 
Function created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create table t ( x int );
 
Table created.
 
ops$tkyte@ORA9IR2> insert into t values ( 1 );
 
1 row created.
 
ops$tkyte@ORA9IR2> commit;
 
Commit complete.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace view V
  2  as
  3  select *
  4    from t
  5   where x in ( select * from TABLE( f('a,b,c') ) )
  6  /
 
View created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create user a identified by a;
 
User created.
 
ops$tkyte@ORA9IR2> grant create session to A;
 
Grant succeeded.
 
ops$tkyte@ORA9IR2> grant select on v to a;
 
Grant succeeded.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> @connect a/a
ops$tkyte@ORA9IR2> set termout off
a@ORA9IR2> set termout on
a@ORA9IR2> select * from ops$tkyte.v;
 
         X
----------
         1
 

I am having some problems with this code

Sonali, April 15, 2004 - 9:30 am UTC

create or replace type string_list_t as TABLE OF
VARCHAR2(4000)
/

CREATE OR REPLACE PROCEDURE pr_Time_Phase_Multi
(inWorkID number, inResList varchar2, inLevel number, strSession varchar2, strCreateDate varchar2, strServer varchar2,
inResorWork number, inPhaseType number, inEditView number, strMinStartDate varchar2, strMaxFinishDate varchar2)
IS

inAuthID number;
dtMinStartDate date;
dtMaxFinishDate date;
v_value_list string_list_t := string_list_t( inResList);

Begin

dtMinStartDate := to_date(strMinStartDate,'DD-MON-YYYY');
dtMaxFinishDate := to_date(strMaxFinishDate, 'DD-MON-YYYY');

If inResorWork = 10 Then

DECLARE CURSOR Time_Phase_Multi_Add_Cursor
IS
SELECT Auth_ID
FROM MwebAuth
WHERE Auth_Work_ID = inWorkID AND Auth_Res_ID IN (select * from TABLE ( cast( v_value_list as
string_list_t ) ) );
BEGIN
OPEN Time_Phase_Multi_Add_Cursor;
LOOP
FETCH Time_Phase_Multi_Add_Cursor
INTO inAuthID;
EXIT WHEN Time_Phase_Multi_Add_Cursor %NOTFOUND;

pr_Level_Time_Phase_Multi (inAuthID, inPhaseType, inEditView, strSession, strCreateDate, strServer, dtMinStartDate, dtMaxFinishDate, inResorWork);

pr_Work_Add_Time_Phase (inAuthID, inPhaseType, strSession, strCreateDate, strServer, dtMinStartDate, dtMaxFinishDate);

END LOOP;
CLOSE Time_Phase_Multi_Add_Cursor;
END;

Else

DECLARE CURSOR Time_Phase_Multi_Add_Cursor
IS
SELECT Auth_ID
FROM MwebAuth
WHERE Auth_Res_ID IN (select * from TABLE ( cast( v_value_list as
string_list_t ) ) ) AND (Auth_Work_ID = inWorkID OR Auth_Work_ID IN
(Select Work_ID From MWebWork Where decode (inLeveL, 3, Work_Par3, 4, Work_Par4, 5, Work_Par5, 6, Work_Par6, 7,
Work_Par7, 8, Work_Par8, 9, Work_Par9) = inWorkID));
BEGIN
OPEN Time_Phase_Multi_Add_Cursor;
LOOP
FETCH Time_Phase_Multi_Add_Cursor
INTO inAuthID;
EXIT WHEN Time_Phase_Multi_Add_Cursor %NOTFOUND;

pr_Level_Time_Phase_Multi (inAuthID, inPhaseType, inEditView, strSession, strCreateDate, strServer, dtMinStartDate, dtMaxFinishDate, inResorWork);

pr_Res_Add_Time_Phase (inAuthID, inPhaseType, strSession, strCreateDate, strServer, dtMinStartDate, dtMaxFinishDate);

END LOOP;
CLOSE Time_Phase_Multi_Add_Cursor;
END;

End If;

Commit;
END pr_Time_Phase_Multi;
/

SQLWKS> execute pr_Time_Phase_Multi (40, '0,35,45,47', 0, '3016a35f90d56e4dd1b7eade844a1333aa9989cb', '14-Apr-2004', 'V52DevOR', 10, 30, 10, '01-Mar-2003', '24-Feb-2004');
ORA-01722: invalid number
ORA-06512: at "V52DEVOR.PR_TIME_PHASE_MULTI", line 27
ORA-06512: at line 2

inResList is '0,35,45,47' string which will be only numbers separated by comma. But I get this error. What am I doing wrong ?

Thanks


Tom Kyte
April 15, 2004 - 9:39 am UTC

you didn't parse that list into a list -- you have a single string there- not a collection of numbers.

you need a function like "in_list" above to parse the string into a collection



two different plans with and without the package

Ryan Gaffuri, June 18, 2004 - 4:10 pm UTC

I have tested using a variety of different cardinality values with this case. The plan for the query with your package and one with just an inlist is significantly different. The one with just the inlist is much faster.


select col1, col2
from tab1 ,
tab2
where tab1.col1 in (11524,59741,57276,53858,57372,61617,92828,62925,55869,11508,10119,55100,57118,53571,62202,8058,62616,60272,55847,62452,58885,59115,64515,40796,43194,39041,33675,63595,55082,11563,60155,39424,41371,64616,42339,9170,59371,63434,57269,9314,58395,42707,45563,41237,53776,56989,64013,53788,65417,58467,33671,11518,61082,62364,94073,11581,7364,56726,41149,42333,41626,11559,57290,11520,54975,53617,59199,54867,41609,53896,57053,53901,63888,39815,64022,41642,61865,36767,59956,53960,42954,33721,45404,11558,65177,65340,41018,64594,11561,54153,45356,125382,60827,11527,63866,42780,55013,55033,33732,64491,39246,61977,62092,55050,59570,53741,41092,61478,63428,42479,58723,43192,62917,74739,63163,60223,62264,63392,7369,54442,59963,64172) and
tab1.col1 = tab2.col1 and
tab1.DATEcol >= add_months(tab2.DATEcol, -60)
order by tab1.col1, tab1.DATEcol asc

| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
-------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 298 | 9238 | 8 (0)|
| 1 | SORT ORDER BY | | 298 | 9238 | 8 (0)|
| 2 | HASH JOIN | | 298 | 9238 | 4 (0)|
| 3 | INLIST ITERATOR | | | | |
| 4 | TABLE ACCESS BY INDEX ROWID| tab1 | 122 | 1342 | 2 (50)|
| 5 | INDEX RANGE SCAN | tab1.datecolIND | 1 | | 1 (0)|
| 6 | INLIST ITERATOR | | | | |
| 7 | TABLE ACCESS BY INDEX ROWID| tab2 | 290K| 5679K| 2 (0)|
| 8 | INDEX RANGE SCAN | tab2.col1IND | 290K| | 1 (0)|


Now here it is with your package:

please assume concatenation of the inlist string

select tab1.col1
tab1.col2
from tab1,
tab2
where tab1.col1 in (( (SELECT * FROM TABLE( CAST( GETINLIST.GetNumberList( '11524,59741,57276,53858,57372,61617,92828,62925,55869,11508,10119,55100,57118,53571,62202,8058,62616,
60272,55847,62452,58885,59115,64515,40796,43194,39041,33675,63595,55082,11563,60155,
39424,41371,64616,42339,9170,59371,63434,57269,9314,58395,42707,45563,
41237,53776,56989,64013,53788,65417,58467,33671,11518,61082,62364,94073,
11581,7364,56726,41149,42333,41626,11559,57290,11520,54975,53617,59199,54867,
41609,53896,57053,53901,63888,39815,64022,41642,61865,36767,59956,53960,42954,
33721,45404,11558,65177,65340,41018,64594,11561,54153,45356,125382,60827,11527,63866,
42780,55013,55033,33732,64491,39246,61977,62092,55050,59570,53741,41092,61478,63428,
42479,58723,43192,62917,74739,63163,60223,62264,63392,7369,54442,59963,64172' ) AS NUMBERTABLETYPE )) t WHERE ROWNUM >=0) )) and
tab1.col1 = tab2.col1 and
col1..DATEcol >= add_months(tab2.DATEcol, -60)
order by tab1.col1, tab1.DATEcol asc


| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2383 | 102K| 44 (3)|
| 1 | SORT ORDER BY | | 2383 | 102K| 44 (3)|
| 2 | HASH JOIN | | 2383 | 102K| 24 (5)|
| 3 | TABLE ACCESS FULL | tab1 | 5961 | 65571 | 5 (0)|
| 4 | TABLE ACCESS BY INDEX ROWID | tab2 | 2383 | 47660 | 2 (50)|
| 5 | NESTED LOOPS | | 47668 | 1536K| 16 (7)|
| 6 | VIEW | VW_NSO_1 | 20 | 260 | |
| 7 | SORT UNIQUE | | 20 | | |
| 8 | COUNT | | | | |
| 9 | FILTER | | | | |
| 10 | COLLECTION ITERATOR PICKLER FETCH| GETNUMBERLIST | | | |
| 11 | INDEX RANGE SCAN | tab2col1IND | 2383 | | 1 (0)|
------------------------------------------------------------------------------------------------------------------

I tried a variety of different cardinality hints. I attempted some simple hints to try to re-create the first plan, but I am finding I Have to do give a series of hints and be very invasive in order to re-create the plan without your package?

Does this happen often? Any suggestions on identifying why this is happening?

Tom Kyte
June 18, 2004 - 4:43 pm UTC

how often is this particular query to be executed.

and have you considered a global temporary table?

sorry about the formatting....

Ryan Gaffuri, June 18, 2004 - 4:10 pm UTC

you can email me and I can get you the plans. I couldn't get the format right with ASCII

Developer Runtime Bug

Ahmed Yousri, June 19, 2004 - 5:38 am UTC

Hi All
I have a problem with Developer Runtime:
My project Oracle developer 6i ,is flexible direction (then at
new form instance I determines the runtime direction) and I
interested about new developer 6i update
(I use last oracle developer patch -15 )
But the all runtime Terminate (shutdown) when I opens form or navigate to
an item and when I recompile the form ( delete fmx file and recreate it ) the problem
was solve but after some time the problem was raise again Â….
Please help me if you can and thanks a lot

Tom Kyte
June 19, 2004 - 8:08 am UTC

nothing to do with the question....

and nothing I could answer -- don't really use forms, not since 1995 anyway. Try metalink.oracle.com please

global temporary table?

Ryan Gaffuri, June 21, 2004 - 8:32 am UTC

how would a global temporary table help? The values for this query will be different every time its run. Same with the number of values in the inlist.

The query comes from the software engineering side of the house and they do not know how often it will be run.... Even if its run rarely it takes over 2 minutes to complete and without the package it takes about 3 seconds. Oracle is generating an inaccurate plan. I have checked all my settings such as OCA, OICA, etc... They are appropriate. I set those a while back.

Tom Kyte
June 21, 2004 - 9:30 am UTC

give it a try.

what to do with a global temporary table

Ryan Gaffuri, June 21, 2004 - 11:02 am UTC

Do you mean first populate a global temporary table with the inlist and then select off the temp table? Can't do that. We are using middle tier session pooling. Each SQL statement can get submitted to a different session...

?

Tom Kyte
June 21, 2004 - 1:57 pm UTC

so? you grab a connection, populate the gtt, query and give the connection back (table empties, on commit delete rows). no worries. you can (and many do) use gtts

gtt

Ryan Gaffuri, June 21, 2004 - 2:13 pm UTC

I didn't set it up, but the way our architecture works...

Populating the GTT would be one session
query would be another call and another session...

I tested this by putting a sql_trace in a logon trigger. Every sql statement resulted in a different session.

I'd need to do it in one sql call...

I have no say in changing this.

Tom Kyte
June 21, 2004 - 8:37 pm UTC

then we cannot do it.

seems like they grab connections too frequently (bug in code). they should grab ONCE per page, not once per statement per page.

explain plan

Ryan Gaffuri, June 22, 2004 - 8:55 am UTC

how common is it for oracle to make a different plan with your variable inlist package and with hard coded values? Is this a rare occurance? Anyway to diagnose why in this case and not in others?

Tom Kyte
June 22, 2004 - 9:29 am UTC

with a list like:

where x in ( 1,2,3,4,5 )

the database knows -- there are 5 things, they are 1,2,3,4,5

when you turn that into:

where x in ( select * from unanalyzed_table )

the database knows, well, not too much. it guesses. look up in this page for "cardinality"

There's something I want to know!

Alan, June 23, 2004 - 5:24 pm UTC

Hi Tom!

I have this case, and I want to know if I'm doing a good choice to deal with and if it will work. Because I've never used this TABLE/CAST before.

What it does: search the tableA+tableB for some records. If found, then update tableA where tableA.id were not found in the search before.

Thanks!

CREATE OR REPLACE TYPE typ_number_table AS TABLE OF NUMBER
/
DECLARE
vetor typ_number_table;
BEGIN
SELECT A.id
BULK COLLECT INTO vetor
FROM tableA A, tableB B
WHERE A.deb_id = w_deb_id
AND B.id_a = A.id
AND B.col = 'A';

IF vetor.COUNT > 0 THEN
UPDATE tableA
SET ind = 'C'
WHERE deb_id = w_deb_id
AND id NOT IN ( SELECT column_value FROM TABLE( CAST( vetor AS typ_number_table ) ) );
ELSE
--Do other ops
NULL
END IF;
END;

Tom Kyte
June 24, 2004 - 8:28 am UTC

I'd probably just

-- look for at least one row on the join....
select count(*) into l_cnt
from dual
where exists ( select null
from tablea a, tableb b
WHERE A.deb_id = w_deb_id
AND B.id_a = A.id
AND B.col = 'A' );

-- if found update
if ( l_cnt = 1 )
then
update tablea
set ind = 'C'
where deb_id = w_deb_id
and id not in ( select id_a
from tableb
where col = 'A' );
else
other process....
end if;


and make sure that

o id_a is NOT NULL in the table definition of tableb or add "and id_a is not null" to the subquery

o you use the CBO to make not in "effecient"




what if the string it self is more than 4k

A reader, July 21, 2004 - 3:57 pm UTC

ops$tkyte@dev8i> select *
2 from THE
( select cast( in_list('abc, xyz, 012') as
mytableType ) from dual ) a
3 /


here


cast( in_list('MORE THAN 4k the what ?') as mytableType )

if the inlist string is more than 4k what is oracle recomaonded work around ?

Tom Kyte
July 21, 2004 - 7:02 pm UTC

put the data into a global temporary table and query that.

Varray ? or gtt ?

A reader, July 22, 2004 - 11:45 am UTC


varray or gtt ?

A reader, July 22, 2004 - 10:01 pm UTC

Hi tom, can you guide me in an application procedure,
I have a need of sending 4k values in the IN clause ?
the string if I make, is more then 4k chars so I can not put it in varchar2 variable. I am using varray (size 4000) and load all the values in it and then using bulk update(forall...) I udated about 4k rows it just takes under
80 mili sec. so it is fast, but as you suggested should I use
'gtt' ? did I do it wrong way ?

Tom Kyte
July 23, 2004 - 8:29 am UTC

if you are happy with the response time and approach and it meets or exceeds your performance requirements -- it sounds good to me.

using a varray is another way to do it -- sort of like an "in memory gtt"


question

A reader, August 14, 2004 - 5:24 pm UTC

"Additionally, it uses dynamic sql in PLSQL when it doesn't need to -- another
performance hit (no cursor caching, more parses per session, less scalable, less
performant)."

how does dynamic sql result in more parses per session ?

thanx!

Tom Kyte
August 14, 2004 - 7:01 pm UTC

plsql automagically caches static SQL in plsql, when close a static sql cursor -- plsql says "umm, no, i don't want to", keeps it open as long as it can and just reuses it later. dynamic sql is parsed, executed and closed -- not as efficient.

ops$tkyte@ORA9IR2> @test
ops$tkyte@ORA9IR2> create or replace procedure p1
  2  as
  3          l_cursor sys_refcursor;
  4          l_n      number;
  5  begin
  6          select count(*) into l_n from dual look_for_me1;
  7          execute immediate 'select count(*) from dual look_for_me2' into l_n;
  8  end;
  9  /
 
Procedure created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace procedure p2
  2  as
  3  begin
  4          for i in 1 .. 10
  5          loop
  6                  p1;
  7          end loop;
  8  end;
  9  /
 
Procedure created.
 
ops$tkyte@ORA9IR2> @connect /
ops$tkyte@ORA9IR2> set termout off
ops$tkyte@ORA9IR2> set termout on
ops$tkyte@ORA9IR2> @trace
ops$tkyte@ORA9IR2> alter session set events '10046 trace name context forever, level 12';
 
Session altered.
 
ops$tkyte@ORA9IR2> exec p2
 
PL/SQL procedure successfully completed.
 


SELECT count(*) from dual look_for_me1
                                                                                                          
call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute     10      0.00       0.00          0          0          0           0
Fetch       10      0.00       0.00          0         30          0          10
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       21      0.00       0.00          0         30          0          10
                                                                                                          
********************************************************************************
select count(*) from dual look_for_me2
                                                                                                          
call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse       10      0.00       0.00          0          0          0           0
Execute     10      0.00       0.00          0          0          0           0
Fetch       10      0.00       0.00          0         30          0          10
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       30      0.00       0.00          0         30          0          10


<b>yes, in 10g, things are "different", there is some caching of dynamic sql going on but the rule is, was, will be -- if you can do it in static sql, by all means DON'T even consider dynamic</b>

 

bug ... or misunderstanding on my part?

Gabe, August 17, 2004 - 3:42 pm UTC

[Versions and resources at the end]

A colleague working on a pl/sql function (something for some ad-hoc querying) asked me to help with some dynamic sql requiring a variable list of bind variables (the same array is used for all the binds) Â… I suggested using subquery factoring in order to always have exactly one bind variable Â… we hit some problems Â… I eliminated the dynamic sql as the culprit Â… and built a simplified test case with static sql showing the problem Â… can you comment?

The combination of "union all", "subquery factoring", "IN lists" and "casting of the array variable" seems to produce the error.

--
-- test case #1
--
-- the sql shown here is similar to what we would like to generate
-- but it doesn't work ...
--
-- ERROR at line 1:
-- ORA-00932: inconsistent datatypes: expected - got -
-- ORA-06512: at line 7
--
declare
idarr num_array := num_array(1,6);
rc xpkg.ref_cursor;
v varchar2(10);
n number;
begin
open rc for
with idtab as (select column_value as pid
from table(cast(idarr as num_array)))
select t.pst, count(0) cnt
from ( select rownum rn,pid,pst from xa
where pid in (select pid from idtab)
union all
select rownum rn,pid,pst from xb
where pid in (select pid from idtab)
) t
group by t.pst
;
loop
fetch rc into v,n;
exit when rc%notfound;
dbms_output.put_line('pst='||v||' cnt='||n);
end loop;
close rc;
end;
/

--
-- test case #2
--
-- works ... removed the union all
--
declare
idarr num_array := num_array(1,6);
rc xpkg.ref_cursor;
v varchar2(10);
n number;
begin
open rc for
with idtab as (select column_value as pid
from table(cast(idarr as num_array)))
select t.pst, count(0) cnt
from ( select rownum rn, pid,pst from xa
where pid in (select pid from idtab)
-- union all
-- select rownum rn, pid,pst from xb
-- where pid in (select pid from idtab)
) t
group by t.pst
;
loop
fetch rc into v,n;
exit when rc%notfound;
dbms_output.put_line('pst='||v||' cnt='||n);
end loop;
close rc;
end;
/


--
-- test case #3
--
-- works ... removed the subquery factoring
--
declare
idarr num_array := num_array(1,6);
rc xpkg.ref_cursor;
v varchar2(10);
n number;
begin
open rc for
select t.pst, count(0) cnt
from ( select rownum rn,pid,pst from xa
where pid in (select column_value as pid
from table(cast(idarr as num_array)))
union all
select rownum rn,pid,pst from xb
where pid in (select column_value as pid
from table(cast(idarr as num_array)))
) t
group by t.pst
;
loop
fetch rc into v,n;
exit when rc%notfound;
dbms_output.put_line('pst='||v||' cnt='||n);
end loop;
close rc;
end;
/

--
-- test case #4
--
-- works ... removed the 'in' lists and replaced with join outside the inline (union all) view
--
declare
idarr num_array := num_array(1,6);
rc xpkg.ref_cursor;
v varchar2(10);
n number;
begin
open rc for
with idtab as (select column_value as pid
from table(cast(idarr as num_array)))
select t.pst, count(0) cnt
from ( select rownum rn,pid,pst from xa
union all
select rownum rn,pid,pst from xb
) t
,(select pid from idtab) w
where t.pid = w.pid
group by t.pst
;
loop
fetch rc into v,n;
exit when rc%notfound;
dbms_output.put_line('pst='||v||' cnt='||n);
end loop;
close rc;
end;
/

--
-- test case #5
--
-- works ... removed the array variable
--
declare
idarr num_array := num_array(1,6);
rc xpkg.ref_cursor;
v varchar2(10);
n number;
begin
open rc for
with idtab as (select column_value as pid from table(num_array(1,6)))
select t.pst, count(0) cnt
from ( select rownum rn, pid,pst from xa
where pid in (select pid from idtab)
union all
select rownum rn, pid,pst from xb
where pid in (select pid from idtab)
) t
group by t.pst
;
loop
fetch rc into v,n;
exit when rc%notfound;
dbms_output.put_line('pst='||v||' cnt='||n);
end loop;
close rc;
end;
/

Versions:
---------
SQL*Plus: Release 9.2.0.1.0 - Production on Tue Aug 17 14:58:36 2004

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Connected to:
Oracle9i Enterprise Edition Release 9.2.0.4.0 - Production
With the Partitioning, OLAP and Oracle Data Mining options
JServer Release 9.2.0.4.0 - Production

Resources:
----------
create or replace type num_array as table of number;
/

create or replace package xpkg as
type ref_cursor is ref cursor;
end;
/

create table xa (pid number primary key, pst varchar2(10) not null);
create table xb (pid number primary key, pst varchar2(10) not null);

insert into xa values (1,'one');
insert into xa values (2,'two');
insert into xa values (6,'six');

insert into xb values (1,'one');
insert into xb values (2,'two');
insert into xb values (6,'six');

Thanks.


Tom Kyte
August 17, 2004 - 4:33 pm UTC

this is sufficient to show the bug, do you have support? this sort of clear concise test case will make it really easy for you to file an itar to get this bugged. if not, i can do it, but it looks best from you (would be a relatively low priority one from me here, easy workaround)


create or replace type num_array as table of number;
/

create table xa (pid number primary key, pst varchar2(10) not null);
insert into xa values (1,'one');

variable x refcursor
declare
idarr num_array := num_array(1,6);
begin
open :x for
with idtab as (select column_value as pid
from table(cast(idarr as num_array)))
select t.pst, count(0) cnt
from ( select rownum rn,pid,pst from xa
where pid in (select pid from idtab)
union all
select rownum rn,pid,pst from xa
where pid in (select pid from idtab)
) t
group by t.pst;
end;
/
print x

declare
idarr num_array := num_array(1,6);
begin
open :x for
select t.pst, count(0) cnt
from ( select rownum rn,pid,pst from xa
where pid in
(select column_value as pid
from table(cast(idarr as num_array)))
union all
select rownum rn,pid,pst from xa
where pid in
(select column_value as pid
from table(cast(idarr as num_array)))
) t
group by t.pst;
end;
/
print x


you should probably file it ...

Gabe, August 17, 2004 - 5:31 pm UTC

I personally don't have support ... the company I currently work for has it ... but isn't the metalink a resource the DBA will never share (well, maybe rarely) with developers? :)

As for workarounds ... we already worked out that. What you suggested (test case #3) is what we started with ... as I said, the sql is actually being generated and executed dynamically ... the number of selects being "union all"ed in the inline view is variable and, with the "idarr" replaced with binds, we get this variable number of them:

open rc for 'select ... :x1 union all ... :x2 ... union all ... '
using idarr, idarr, <more idarr> ....

(there are other variable pieces in there as well)

Hence the approach using the subquery factoring.

My colleague (his call on this one) decided to go with the construct shown in test case #4 (we don't have the rownum in the real thing) even if the little testing that we had done shows that the union all is resolved first ... the inline view gets _materialized_ prior to the substantial filtering by the ids from the array. In any case, we are isolated from the front-end through our stored procedure ... we'll revise it if in proves a performance killer ... for now he wants the functionality quickly out the door.

I would've preferred to dump the array into a gtt ... but that would've required the data architect/modeler to make provisions for it ... (our) history proves one never gets too far _reasoning_ with him. Both I and my colleague eliminated this option pretty quickly.

Should we get into a performance crunch, we can always do a case in the sp as:
if <one bind needed > then
open rc for '...:x1 ...' using idarr;
elsif <two binds needed > then
open rc for '...:x1...:x2...' using idarr, idarr;
...
there is a max of 30 we can count on.

Ugly but would do the job.

Any other options are welcomed.


Suggestion for In_List function

Mark, August 18, 2004 - 11:46 am UTC

I have found the in_list function extremely useful for avoiding dynamic sql for Crystal Reports requiring many search criteria.

I would humblly like to suggest an additional function to
hide some of the details in the select statement. I ran into the problem of having to determine whether the string of values was Null, meaning the clause should be ignored by the select. At first I tried to deal with this in the select but it became a bit messy. I then created the following function call "criteria" which then uses the in_list function. Criteria can be used in pl/sql within a select statement as follows:

Select mycolumn from mytable
where criteria(mytable.mytable_id, p_String)= 1;
----
create or replace function criteria( p_DBColumnValue in varchar2,p_StringofValues in varchar2 )
return Integer
as

vReturn Integer := 0;

begin
If p_StringofValues is NULL Then
vReturn := 1;
Else
Select 1 into vReturn
from Dual
where p_DBColumnValue in (select * from THE
( select cast( in_list(p_StringofValues) as
InListType ) from dual )); End if;

return vReturn;

end criteria;


I am sure it can be improved. Thanks for the help. Any suggestion are appreciated.



In Clause Review

Giovanni Jaramillo, August 18, 2004 - 4:19 pm UTC

I used to create collection types (i.e. arrays) within my procedures/functions then use them to store values and select from them one by one but this new method is very powerful and flexible. I wasn't aware that I could create schema level collections. Also my first time using the TABLE and CAST functions. Learned something new.

Thanks Tom.
Gio

A simpler solution if you don't have fixed list of In value

celia_wang, August 23, 2004 - 6:02 pm UTC

CREATE TABLE address
(id NUMBER(15,0),
addr1 VARCHAR2(50),
city VARCHAR2(50),
state VARCHAR2(2));

If you have in Parameter like 'LA, TX, CA'
OR 'LA, CA', OR 'CA', OR 'ALL' and so on.

CREATE or replace PROCEDURE P_GET_STATE
(
in_state IN VARCHAR2,
out_search OUT SYS_REFCURSOR)
IS
BEGIN
open out_search for
select * from address
where ( INSTR(IN_state, state ) > 0 or IN_state = 'ALL');
END;
/

Tom Kyte
August 23, 2004 - 7:47 pm UTC

ok, now, use the index?

Yeah, you are right about index. Thanks!

celia_wang, August 24, 2004 - 11:56 am UTC

But, if you have one search screen with many fields in it,
you have to build many collections for those fileds.



Tom Kyte
August 24, 2004 - 3:18 pm UTC

nah, a single varchar2(4000) collection type will work for anything

use to_number or to_date on the column_value if need be but a single collection type should do it.

Thanks a lot!

celia_wang, August 24, 2004 - 6:07 pm UTC

I got it. To reuse the same collection in the where clause as many time as you want.

select *
from address
where state in (select * from THE(select cast(f_in_list('TX, LA') AS mySearchType) FROM DUAL) )
and dob in (select * from THE(select cast(f_in_list('14-AUG-2004,15-aug-2004') AS mySearchType) FROM DUAL))
and id in (select * from THE(select cast(f_in_list('1,2') AS mySearchType) FROM DUAL))

I just bought your book. It is on the way. I cannot wait to read them.

parse a string

maryW, October 27, 2004 - 4:30 pm UTC

Hi, Tom

I am using your in_list function to parse a string.

in_search_str varchar2(256) :='Rage,Against,The,Machine';
search_array myTableType := parse_string(in_search_str);
search_word varchar2(256);

i then iterate through the array:

for i in 1 .. search_array.count loop

search_word := search_array(i);

end loop;

however i am getting : PL/SQL: numeric or value error: character to number conversion error

what am i doing wrong here?


Tom Kyte
October 27, 2004 - 4:38 pm UTC

entire example (including "my code")......




here is the entire example

Mary W, October 27, 2004 - 4:52 pm UTC

CREATE OR REPLACE FUNCTION XMR.parse_string( p_string in VARCHAR2)




RETURN myTABLEType
AS
l_data myTableType := myTableType();
l_string LONG default p_string || ',';
l_n NUMBER;
BEGIN
Loop
EXIT WHEN l_string is null;
l_data.extend;
l_n := instr(l_string, ',');
l_data(l_data.count) := substr(l_string,1, l_n-1);
l_string := substr(l_string, l_n+1);

End Loop;
RETURN l_data;
END;
/

CREATE OR REPLACE procedure XMR.search_str (in_search_str IN varchar2)
is

search_array myTableType := parse_string(in_search_str);

search_word varchar2(200);

begin


for i in 1 .. search_array.count loop

search_word := search_array(i);

insert into chanadv_artist (string) values(search_word );


end loop;


end;
/


Tom Kyte
October 27, 2004 - 5:56 pm UTC

nope, I'm missing a create type, i'm missing a create table.........

here is the rest of the code

Mary W, October 28, 2004 - 10:29 am UTC

create or replace type myTableType as table
of varchar2 (255);


CREATE TABLE search_word (
STRING VARCHAR2 (100));

Tom Kyte
October 28, 2004 - 1:49 pm UTC

ops$tkyte@ORA9IR2> create or replace type myTableType as table of varchar2 (255);
  2  /
 
Type created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> drop table chanadv_artist;
 
Table dropped.
 
ops$tkyte@ORA9IR2> CREATE TABLE chanadv_artist ( STRING  VARCHAR2 (100));
 
Table created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> CREATE OR REPLACE FUNCTION parse_string( p_string in VARCHAR2)
  2    RETURN myTABLEType
  3     AS
  4     l_data         myTableType := myTableType();
  5     l_string       LONG default p_string || ',';
  6     l_n            NUMBER;
  7      BEGIN
  8           Loop
  9            EXIT WHEN l_string is null;
 10        l_data.extend;
 11        l_n := instr(l_string, ',');
 12        l_data(l_data.count) := substr(l_string,1, l_n-1);
 13        l_string := substr(l_string, l_n+1);
 14       End Loop;
 15       RETURN l_data;
 16  END;
 17  /
 
Function created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> CREATE OR REPLACE procedure search_str (in_search_str IN varchar2)
  2   is
  3       search_array myTableType := parse_string(in_search_str);
  4       search_word varchar2(200);
  5   begin
  6             for i in 1 .. search_array.count loop
  7                 search_word := search_array(i);
  8                 insert into chanadv_artist (string) values(search_word );
  9             end loop;
 10  end;
 11  /
 
Procedure created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> exec search_str( 'Rage,Against,The,Machine' );
 
PL/SQL procedure successfully completed.
 
<b>try again -- give us the ENTIRE test case, from start to finish -- with everything (eg: table is not called search_word apparently)

What I need, what ANYONE would need is a full test case (like I give you) with everything -- so we can see the actual error ourselves!!!</b>
 

I figured it out!

Mary W, October 28, 2004 - 10:59 am UTC

ok it was mistake on my part. i re-created my type and my function and all works now... THanks! sorry for taking your time.

:)

Multiple In Clauses

Vinnie, November 02, 2004 - 3:58 pm UTC

Tom,

What would the best way be to return a result set using multiple IN Clauses.

i.e.

create table test (id char(10), desc char(10));
insert into test values ('1','test');
insert into test values ('2','test1');
insert into test values ('1','test1');
insert into test values ('1','test1');
insert into test values ('1','test3');

Group by id where desc in test1 or test2

Output desired:
ID count(test) count(test1)
1 1 2
2 0 1


Tom Kyte
November 03, 2004 - 6:38 am UTC

desc -- bad name, desc is a keyword
char -- char stinks, use varchar2
desc in test1 or test2 -- but the answer you show is for test and test1

arg -- makes it really hard to start and stop and start and stop with such examples!

ops$tkyte@ORA9IR2> variable v1 varchar2(25)
ops$tkyte@ORA9IR2> variable v2 varchar2(25)
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> exec :v1 := 'test'; :v2 := 'test1'
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> select id,
  2         count( case when descript = :v1 then 1 end ) cnt1,
  3         count( case when descript = :v2 then 1 end ) cnt2
  4    from test
  5   where descript in ( :v1, :v2 )
  6   group by id
  7  /
 
ID               CNT1       CNT2
---------- ---------- ----------
1                   1          2
2                   0          1
 
ops$tkyte@ORA9IR2> exec :v1 := 'test1'; :v2 := 'test2'
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> /
 
ID               CNT1       CNT2
---------- ---------- ----------
1                   2          0
2                   1          0
 
ops$tkyte@ORA9IR2>

 

Can't we do it without creating a function...

Venkat, November 23, 2004 - 6:59 pm UTC

This question (IN list) came up a couple of times where I work and I was trying to find a way to do it in SQL .. Going back to your first example of selecting from all_users, can you please tell me if you see any problems with my approach ..

SQL> variable x varchar2(1000);
SQL> variable delim varchar2(10);
SQL> exec :x := 'ORACLE,DBSNMP,,SYS,SYSTEM,,,,'; :delim := ',';

PL/SQL procedure successfully completed.

SQL> select * from all_users where username in
  2    (select substr(str,pos_curr,pos_next-pos_curr-delim_len) val
  3       from (select :x str, length(:delim) delim_len,
  4                    instr(:delim||:x||:delim,:delim,1,rownum) pos_curr,
  5                    instr(:delim||:x||:delim,:delim,1,rownum+1) pos_next
  6               from (select '' from dual group by cube(1,2,3,4,5,6,7,8,9,10))
  7            --max 1024 elements in list 
  8              where rownum <= ((length(:x) - length(replace(:x,:delim,'')))/length(:delim)) + 1
  9            )
 10      where pos_next - pos_curr > 1 -- to eliminate comma(s) at the end 
 11    );

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
SYS                                     0 19-JUL-04
SYSTEM                                  5 19-JUL-04
DBSNMP                                 19 19-JUL-04
ORACLE                                 27 21-JUL-04

SQL> exec :x := 'ORACLE/#DBSNMP/#/SYS/#SYSTEM/#'; :delim := '/#';

PL/SQL procedure successfully completed.

SQL> /

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
SYSTEM                                  5 19-JUL-04
DBSNMP                                 19 19-JUL-04
ORACLE                                 27 21-JUL-04

SQL> exec :x := 'ORACLE//DBSNMP///SYS//SYSTEM//'; :delim := '//';

PL/SQL procedure successfully completed.

SQL> /

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
SYS                                     0 19-JUL-04
SYSTEM                                  5 19-JUL-04
DBSNMP                                 19 19-JUL-04
ORACLE                                 27 21-JUL-04

The one issue as you can see is when the delimiter consists of the same character repeating; the sql ignores any "extra" repititions of the delim character (DBSNMP///SYS is treated the same way as DBSNMP//SYS).

Thanks. 

Tom Kyte
November 23, 2004 - 7:55 pm UTC

somethings can be done, but we must ask "why"

str2table:

create or replace type str2tblType as table of varchar2(30)
/

create or replace function str2tbl( p_str in varchar2, p_delim in varchar2 default ',' ) return str2tblType
PIPELINED
as
l_str long default p_str || p_delim;
l_n number;
begin
loop
l_n := instr( l_str, p_delim );
exit when (nvl(l_n,0) = 0);
pipe row( ltrim(rtrim(substr(l_str,1,l_n-1))) );
l_str := substr( l_str, l_n+1 );
end loop;
return;
end;
/


is so small, versitile and just "there".

IN String

Dennis, November 24, 2004 - 3:30 am UTC

Dear Tom,

The Question is some what same. I too experiance the same problem.

I have tried with even REF cursor but this does not work. Scott database and emp table as example.

Please help me. Thanks in advance.

Regards
Dennis

  1  DECLARE
  2    S_ENAME VARCHAR2(100);
  3    CURSOR C_EMP IS
  4    SELECT ENAME FROM EMP WHERE ENAME=S_ENAME ;
  5  BEGIN
  6     IF C_EMP%ISOPEN THEN
  7        CLOSE C_EMP;
  8     END IF;
  9     S_ENAME := '''WARD' || ''',''' || 'SCOTT''';
 10     DBMS_OUTPUT.PUT_LINE(S_ENAME);
 11     OPEN C_EMP;
 12     LOOP
 13        FETCH C_EMP INTO S_ENAME;
 14        DBMS_OUTPUT.PUT_LINE('DENNIS');
 15        EXIT WHEN C_EMP%NOTFOUND;
 16        DBMS_OUTPUT.PUT_LINE('I AM NOT FIRED');
 17        DBMS_OUTPUT.PUT_LINE(S_ENAME);
 18     END LOOP;
 19     CLOSE C_EMP;
 20* END;
SQL> /
'WARD','SCOTT'
DENNIS

PL/SQL procedure successfully completed. 

Tom Kyte
November 24, 2004 - 7:29 am UTC

please re-read the original answer to the first question.

it basically says "hey, you cannot in any way shape or form do that, you have totally misunderstood"


your query is:

select ename from emp where ename = 'WARD,SCOTT';

(quotes left out for readability)

you have no one by that name.


you want

where ename in ( 'WARD', 'SCOTT' );


but you cannot use:

where ename in ( s_ename );

because s_ename is a SINGLE VALUE -- so you need a set. back to square one, read the original answer again.

How can I do a variable "in list"

Dennis, November 24, 2004 - 7:46 am UTC

But this works in SQL Server 2000. So i am trying the same here. oooooh. I am converting SQL Server procedure to oracle.

The situation to me is i have 'N' number of tables in which i have to search for particular value or list of value.

Here value is passed to a procedure which calculates result from 'N' number of tables. If i pass value one by one then i have to make more round trips for each value which is impossible because it takes more time. To make it simple i concatenate all to one string and pass to next procedure where it checks with IN.

I am planning to use GLOBAL TEMPORARY TABLE.

Is there any other good option. Expecting your expert advice.

Thanks a lot for your reply.




Tom Kyte
November 24, 2004 - 8:03 am UTC

in sqlserver this did "not work"

in sqlserver you built a dynamic sql statment and executed. same would work in oracle but it would scale no better than sqlserver did (eg: not well)


did you actually read the original answer?

Got an pl/sql table array

robert, December 16, 2004 - 11:50 am UTC

8.1.7.4
--------------
Tom,
given a array of the type - say owa_util.ident_arr.
Is there a way in 8i to DIRECTLY use this pl/sql table in
SQL (static or dynamic) as in "PROCEDURE two" below.

(what i been doing is convert the array to a delimited string and apply your old "magic" above. ;)
thanks

PACKAGE BODY test IS

g_big_array owa_util.ident_arr;

PROCEDURE one
IS
BEGIN
SELECT object_id BULK COLLECT INTO g_big_array
FROM all_objects ;
END ;

PROCEDURE two
IS
BEGIN
one;
INSERT INTO TABLE my_objects
SELECT * FROM all_objects WHERE object_id IN <<g_big_array>>
END ;

END test ;

Tom Kyte
December 16, 2004 - 12:03 pm UTC

no, not directly as a set.

where x in ( array(1), array(2), array(3), ... array(n) )

would work - but you need to know N at compile time.

else you must move into a SQL collection type.

Trouble with Clob !

Shiju, April 28, 2005 - 11:37 am UTC

Tom,
First of all, Thanks for ask tom!! Your answers are excellent.

I was using the Bind variable and IN in Dynamic Sql. So I decided to use the solution in the beginning of the page. Instead of “long” I used “Clob” Datatype and got into trouble with Function in_list ( it went into infinite loop !)

it is better explained by the below piece of code..

declare
a Clob :='';
begin
if a is null then
dbms_output.put_line('a is null-1');
else
dbms_output.put_line('a is not null-1');
end if;

a := 'abc';
if a is null then
dbms_output.put_line('a is null-2');
else
dbms_output.put_line('a is not null-2');
end if;

a := substr(a,4);

if a is null then
dbms_output.put_line('a is null-3');
else
dbms_output.put_line('a is not null-3');
dbms_output.put_line('Length of a:'||length(a));
end if;
end;

Output::
a is null-1
a is not null-2
a is not null-3
Length of a:0

Is it a bug?? Please respond. Thanks in advance

Tom Kyte
April 28, 2005 - 1:53 pm UTC

an empty_clob is not a NULL clob.

no bug.

Null Clob

Shiju, April 29, 2005 - 3:02 am UTC

But initially Clob responded to NULL ! ie, "a is null-1" output.

But after assigning some values and then if we remove the value, Clob is not responding to NULL! Why is it not consistent?

Anyway now i can handle it using length.

Thanks

Tom Kyte
April 29, 2005 - 8:21 am UTC

when you assign null to a clob, it is null.

when you assigned an empty clob to a clob, it is an empty clob.

Not using the index

Anil, April 30, 2005 - 11:39 am UTC

Hi Tom 

In_list is vesy usefull but I ma having a problem here since it is using a full scan instead of inex scan. When I use rule hint it uses index. What could be the problem. I am using 9i 9.2.0.6 


NGCS_DEV@NGCSD-SQL> create table cfr_test as select * from all_objects;

Table created.

NGCS_DEV@NGCSD-SQL> create index cfr_test_ind on cfr_test (object_id);

Index created.

NGCS_DEV@NGCSD-SQL> analyze table cfr_test compute statistics;

Table analyzed.

NGCS_DEV@NGCSD-SQL>  analyze index cfr_test_ind compute statistics;

Index analyzed.

NGCS_DEV@NGCSD-SQL> set autot on
NGCS_DEV@NGCSD-SQL>  UPDATE cfr_test cfr
       SET object_type =  'Anil'
       WHERE object_id IN (select * from
                  table (cast (gen_util.in_list('8658') AS numtabletype)) a)  2    3    4
  5  /

1 row updated.


Execution Plan
----------------------------------------------------------
   0      UPDATE STATEMENT Optimizer=CHOOSE (Cost=80 Card=1 Bytes=14)
   1    0   UPDATE OF 'CFR_TEST'
   2    1     HASH JOIN (SEMI) (Cost=80 Card=1 Bytes=14)
   3    2       TABLE ACCESS (FULL) OF 'CFR_TEST' (Cost=57 Card=26529 Bytes=318348)
   4    2       COLLECTION ITERATOR (PICKLER FETCH) OF 'IN_LIST'




Statistics
----------------------------------------------------------
          8  recursive calls
          2  db block gets
        403  consistent gets
          0  physical reads
        372  redo size
        435  bytes sent via SQL*Net to client
        586  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
          1  rows processed


Rule Based

NGCS_DEV@NGCSD-SQL>  UPDATE /*+ rule */ cfr_test cfr
       SET object_type =  'Anil'
       WHERE object_id IN (select * from
                  table (cast (gen_util.in_list('8658') AS numtabletype)) a)  2    3    4
  5  /

1 row updated.


Execution Plan
----------------------------------------------------------
   0      UPDATE STATEMENT Optimizer=HINT: RULE
   1    0   UPDATE OF 'CFR_TEST'
   2    1     NESTED LOOPS
   3    2       VIEW OF 'VW_NSO_1'
   4    3         SORT (UNIQUE)
   5    4           COLLECTION ITERATOR (PICKLER FETCH) OF 'IN_LIST'
   6    2       INDEX (RANGE SCAN) OF 'CFR_TEST_IND' (NON-UNIQUE)




Statistics
----------------------------------------------------------
          0  recursive calls
          1  db block gets
          8  consistent gets
          0  physical reads
        244  redo size
        449  bytes sent via SQL*Net to client
        598  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
          1  rows processed

Rgds
Anil  

Full Scan

Anil, April 30, 2005 - 2:24 pm UTC

HI Tom 

That was informative. But I have another problem. I tried the query in 9i and 10g 

in 9i 

NGCS_DEV@NGCSD-SQL> l
  1   UPDATE    cfr_leg cfr
  2         SET modified_by =  'Anil'
  3         WHERE fll_id IN (select /*+ cardinality( a 10 ) */ * from
  4                    table (cast (gen_util.in_list('865058') AS numtabletype)) a where rownum >0 )
  5           AND fsale_wt_bu > 74
  6*          AND fsale_vol_bu > 85
NGCS_DEV@NGCSD-SQL> /

1 row updated.


Execution Plan
----------------------------------------------------------
   0      UPDATE STATEMENT Optimizer=CHOOSE (Cost=33 Card=10 Bytes=250)
   1    0   UPDATE OF 'CFR_LEG'
   2    1     NESTED LOOPS (Cost=33 Card=10 Bytes=250)
   3    2       VIEW OF 'VW_NSO_1' (Cost=17 Card=10 Bytes=130)
   4    3         SORT (UNIQUE)
   5    4           COUNT
   6    5             FILTER
   7    6               COLLECTION ITERATOR (PICKLER FETCH) OF 'IN_LIST'
   8    2       TABLE ACCESS (BY INDEX ROWID) OF 'CFR_LEG' (Cost=1 Card=1 Bytes=12)
   9    8         INDEX (UNIQUE SCAN) OF 'FLL_PK' (UNIQUE)




Statistics
----------------------------------------------------------
          0  recursive calls
          1  db block gets
          3  consistent gets
          0  physical reads
        244  redo size
        449  bytes sent via SQL*Net to client
        695  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
          1  rows processed

But in 10g 


NGCS_DEV@NGCSWD1-SQL>  UPDATE    cfr_leg cfr
  2         SET modified_by =  'Anil'
  3         WHERE fll_id IN (select /*+ cardinality( a 10 ) */ * from
  4                    table (cast (gen_util.in_list('865058') AS numtabletype)) a where rownum >0 )
  5           AND fsale_wt_bu > 74
  6           AND fsale_vol_bu > 85
  7  /

1 row updated.


Execution Plan
----------------------------------------------------------
   0      UPDATE STATEMENT Optimizer=ALL_ROWS (Cost=843 Card=0 Bytes=0)
   1    0   UPDATE OF 'CFR_LEG'
   2    1     FILTER
   3    2       TABLE ACCESS (FULL) OF 'CFR_LEG' (TABLE) (Cost=335 Card=42 Bytes=504)
   4    2       FILTER
   5    4         COUNT
   6    5           FILTER
   7    6             COLLECTION ITERATOR (PICKLER FETCH) OF 'IN_LIST'




Statistics
----------------------------------------------------------
          0  recursive calls
          1  db block gets
       1509  consistent gets
          0  physical reads
        292  redo size
        647  bytes sent via SQL*Net to client
       1053  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          1  rows processed

I saw that in 10g the cardinality of the temp tables is 1 ...

But how do we tackle this.


Also when I tried the query without rownum in 9i I gott the index scan properly.. This is n contrary to your reply 


Rgds
Anil 

 

Tom Kyte
April 30, 2005 - 3:03 pm UTC

the rownum wasn't contrary, the rownum was used to reduce the number of times the function was called, you didn't measure that.

subquery with factoring seems to be working in this case:

UPDATE cfr_leg cfr
SET modified_by = 'Anil'
WHERE fll_id IN (
with t as ( select * from table (cast (str2tbl('865058') AS str2tblType)) where rownum > 0 )
select * from t )
AND fsale_wt_bu > 74
AND fsale_vol_bu > 85
/


Wrong plan

Anil, May 01, 2005 - 12:51 am UTC

Hi Tom 

A bit dissapointed after seeing the inconsistancy. My database 9iR2. I tried this query and got full scan. Earlier query with cardinality h int was good

NGCS_DEV@NGCSD-SQL> UPDATE    cfr_leg cfr
  2          SET modified_by =  'Anil'
  3          WHERE fll_id IN (
  4          with t as ( select * from table (cast (gen_util.in_list('85058') AS
  5  numtabletype)) where rownum > 0 )
  6          select * from t )
  7            AND fsale_wt_bu > 74
  8            AND fsale_vol_bu > 85
  9  /

0 rows updated.


Execution Plan
----------------------------------------------------------
   0      UPDATE STATEMENT Optimizer=CHOOSE (Cost=343 Card=1 Bytes=2014)
   1    0   UPDATE OF 'CFR_LEG'
   2    1     HASH JOIN (SEMI) (Cost=343 Card=1 Bytes=2014)
   3    2       TABLE ACCESS (FULL) OF 'CFR_LEG' (Cost=227 Card=42047 Bytes=504564)
   4    2       VIEW OF 'VW_NSO_1' (Cost=17 Card=8168 Bytes=16352336)
   5    4         VIEW (Cost=17 Card=8168 Bytes=16352336)
   6    5           COUNT
   7    6             FILTER
   8    7               COLLECTION ITERATOR (PICKLER FETCH) OF 'IN_LIST'




Statistics
----------------------------------------------------------
          5  recursive calls
          0  db block gets
       1496  consistent gets
          0  physical reads
         60  redo size
        439  bytes sent via SQL*Net to client
        699  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          3  sorts (memory)
          0  sorts (disk)
          0  rows processed


Rgds
Anil  

Tom Kyte
May 01, 2005 - 8:31 am UTC

suggest you two step it then.


drop table gtt;

drop table cfr_test;
create table cfr_test as select object_id fll_id, owner modified_by, object_id fsale_wt_bu, object_id
fsale_vol_bu from all_objects;

alter table cfr_test add constraint cfr_test_pk primary key(fll_id);

exec dbms_stats.gather_table_stats( user, 'CFR_TEST', cascade=>true );

create global temporary table gtt ( id number primary key );
exec dbms_stats.set_table_stats( user, 'GTT', numrows => 10 );

insert into gtt
select *
from table (cast (str2tbl('85058') AS str2tblType)) A;

set autotrace traceonly explain
UPDATE (select modified_by
from cfr_test cfr, gtt
where gtt.id = fll_id
AND fsale_wt_bu > 74
AND fsale_vol_bu > 85 )
set modified_by = 'Anil'
/
set autotrace off




In LIst

Anil, May 01, 2005 - 12:08 pm UTC

Hi Tom

Thanks for the suggestion . It is working consistently in 9i and 10g. But one question. What is the impact of using temporary table, IO generattion. I had read some where in your site that you were saying, try to avoid using temp table. Any comments

Rgds
Anil

Tom Kyte
May 01, 2005 - 12:22 pm UTC

I try to avoid temp tables until I have to, this would be an example. inserts and truncates (when you commit or session ends) generate the least amount of IO and unless you really blow the thing up with tons of data, it'll not really be hitting disk (it is cached) to much

Just use dbms_stats once to set representative statistics here as a side note, you would do it after creating..

temp table

Anil, May 02, 2005 - 1:33 am UTC

Thanks Tom, One doubt about Temp table , when you said the data in the temp table does not hit the disk only cached, does temp table use buffer cache memory or PGA to store the data.

Rgds
Anil



Tom Kyte
May 02, 2005 - 8:24 am UTC

they are buffered in the cache. they are subject to undo and consistent reads, rolling back and everything else like anyother block.

Single or multiple gtt

anil, May 04, 2005 - 3:26 am UTC

Hi

In our applicaition we have many places where awe use IN cluase to get child record. Is it better to use one global temporary table for different gtt for different queries. Is there any impact??

Thanks for your suggestion

Rgds
Anil

Tom Kyte
May 04, 2005 - 9:03 am UTC

If you can use one gtt -- that is fine. I would not see the need for a gtt per query here.

Nested Tables and ODP.NET

Yuan, May 05, 2005 - 2:20 pm UTC

I'd like to perform SQL on a collection being passed into my package procedure as a parameter, so I made it a schema-level nested table type and cast it as you recommended in your initial response. The problem ODP.NET does not support binding an array that is not a PL/SQL associative array. Is there any other way to accomplish what I want to do short of looping through the passed in associative array to populate my nested table? I'm using 9i.

RE: Nested Tables and ODP.NET

Mark A. Williams, May 05, 2005 - 3:08 pm UTC

Hi Yuan,

The technique illustrated by Chris Alexander in response to the post on the OTN forums is the way to accomplish this using ODP.NET at this time. I show a similar technique in Chapter 5 of my book - i.e. decomposing into a "series" of associative arrays representing each column.

As Chris points out, it can be a bit of extra work.

</code> http://forums.oracle.com/forums/thread.jsp?forum=146&thread=205160 <code>

- Mark

Thanks Mark

Yuan, May 10, 2005 - 3:56 pm UTC

Thanks for the reply, but that was me on OTN to whom Chris replied. My post on OTN asked if anyone had any alternatives to looping through the Associative Array to populate a nested table. I was just hoping that he was giving me one or that someone else found one.

OTN Post

Mark A. Williams, May 10, 2005 - 10:29 pm UTC

Hi Yuan,

I had figured it was your post on the OTN forums, just wasn't sure if you had seen it yet or not. Object support is probably one of the most requested features for ODP right now.

- Mark

why not use reference cursors

Gabriel, May 11, 2005 - 11:16 am UTC

Hello Tom,

The in list saved me a lot of time but I was wondering why not use reference cursors instead on in varchar2 parameters like so:

function in_list(my_cursor IN my_package.my_cursor_type)
return myTableType
as
l_data myTableType := myTableType();
n number;

my_table myTableType;
begin

fetch my_cursor bulk collect into my_table;
return my_table;
end;

Tom Kyte
May 11, 2005 - 12:23 pm UTC

don't know what you mean?

Extension to array matching...

Andy, May 13, 2005 - 6:09 am UTC

This link has been really helpful. I have used some of things here to compare comma-delimited lists of strings, but I also need to compare wildcards within these strings.

For example:

mires@WS2BMVBW> create table t1(txt1 varchar2(10));

Tabelle wurde angelegt.

mires@WS2BMVBW> insert into t1 values('XX,YY,ZZ');

1 Zeile wurde erstellt.

mires@WS2BMVBW> commit;

Transaktion mit COMMIT abgeschlossen.

mires@WS2BMVBW> create or replace type mirestabletype as table of varchar2(1000);
2 /

Typ wurde erstellt.

mires@WS2BMVBW> create or replace function in_list ( p_string in
2 varchar2 ) return miresTableType
3 as
4 l_string long default p_string || ',';
5 l_data miresTableType := miresTableType();
6 n number;
7 begin
8 loop
9 exit when l_string is null;
10 n := instr( l_string, ',' );
11 l_data.extend;
12 l_data(l_data.count) :=
13 ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
14 l_string := substr( l_string, n+1 );
15 end loop;
16 return l_data;
17 end;
18 /

Funktion wurde erstellt.

mires@WS2BMVBW> create or replace function array_match (
2 p_string1 in varchar2,
3 p_string2 in varchar2
4 )
5 return number
6 is
7 l_found number default 0;
8 begin
9 for x in
10 (
11 select * from TABLE(cast(in_list(p_string1) as mirestabletype))
12 intersect
13 select * from TABLE(cast(in_list(p_string2) as mirestabletype))
14 )
15 loop
16 l_found := 1;
17 exit;
18 end loop;
19 return l_found;
20 end;
21 /

Funktion wurde erstellt.

mires@WS2BMVBW> select txt1 from t1 where 1 = array_match(txt1, 'AA');

Es wurden keine Zeilen ausgewählt

mires@WS2BMVBW> select txt1 from t1 where 1 = array_match(txt1, 'YY');

TXT1
----------
XX,YY,ZZ

mires@WS2BMVBW> select txt1 from t1 where 1 = array_match(txt1, 'X%');

Es wurden keine Zeilen ausgewählt

Is there an easy way to extend this so that XX is matched with X%?

Thank you.

Tom Kyte
May 13, 2005 - 10:19 am UTC

would have to cartesian join and use LIKE on every resulting pair.

should not the persistently stored string be stored as ROWS, not a a string with a list??

Preserve ORDER BY ?

Andy, June 14, 2005 - 4:49 pm UTC

Hi Tom...

Not sure... if this is the right place to post this query ?

But any way here it goes...

create table xxx (n number);

insert into xxx values(1);

insert into xxx values(2);

insert into xxx values(3);

insert into xxx values(4);

insert into xxx values(5);

commit;

Even though the Order in which I have supplied the values is in a different order, i always get the result in the order as shown below and I understand this is how Oracle Fetches the data. 

SQL> select * from xxx where n in (2, 4, 1, 3, 5);

        N
---------
        1
        2
        3
        4
        5

But Is there a way that I can fetch the data in the same order i pass the values in as?

I thought this might work... But looking for a better solution if possible...

create type mytype is table of number;

SQL> select * from xxx where n in (select * from table(mytype(2, 4, 1, 3, 5)));

        N
---------
        2
        4
        1
        3
        5

Do I need to create the TYPE essentially or is there any standard builtin collection like 'SYS%' available for purposes like these... Please help !!! 

Tom Kyte
June 15, 2005 - 3:13 am UTC

Unless and until you have an ORDER BY on your query

YOU CANNOT EXPECT ANYTHING ABOUT THE ORDER OF ROWS RETURNED BY A QUERY

unless and until you have an order by - the rows ordering is RANDOM

period. nothing else is true. nothing can be assumed.

unless you use ORDER BY, the rows are free to come back IN ANY ORDER for ANY QUERY.

how about a really qucik inline way?

Val, June 22, 2005 - 1:56 pm UTC

SELECT * FROM myTable
WHERE
INSTR(vINLISTVAR, ''''||myCol||'''')!=0


Tom Kyte
June 23, 2005 - 1:42 pm UTC

fine, if you want to full scan for every query, which I assumed they would not want to do.

no rule without exception

Matthias Rogel, June 23, 2005 - 4:37 pm UTC

<quote src=tkyte>
Unless and until you have an ORDER BY on your query

YOU CANNOT EXPECT ANYTHING ABOUT THE ORDER OF ROWS RETURNED BY A QUERY

unless and until you have an order by - the rows ordering is RANDOM

period. nothing else is true. nothing can be assumed.

unless you use ORDER BY, the rows are free to come back IN ANY ORDER for ANY
QUERY.
</quote>

not quite true in my eyes

here is one exception to this rule:

in a hierarchical query without siblings the order of
the rows is completely well-defined.

at least documented that way
</code> http://tinyurl.com/al4po <code>

Tom Kyte
June 23, 2005 - 7:17 pm UTC

I believe that order siblings by would "obviously" be considered "order by".

don't you?


and without the order siblings by in a connect by query, the rows can and will come out in any order we like - that preserves the hirearchy. The order siblings by was added purely so you CAN order the results within the hierarchy !!! (eg: without it, you cannot rely on any sort of order from a connect by!)

didn't mention "order siblings by"

Matthias Rogel, June 24, 2005 - 3:00 am UTC

I absolutely agree that
"order siblings by" would "obviously" be considered "order by".

however, I didn't mention "order siblings by" at all.

I said "without siblings"

take for example the query (found quite a few times during the last weeks on this site)

select * from (select level n from dual connect by level <= :b)

I cannot see any "order"
however, due to doc, the ordering of the result is determined


Tom Kyte
June 24, 2005 - 6:38 am UTC

is it -- do you see any promises anywhere that the results will be ordered? I don't see any code that relies on it being ordered (not without an order by)


Where do you see anything that says "it will be ordered"

Using your empirical technique, one could come to the (incorrect) conclusion that group by sorts!

probably ...

Matthias Rogel, June 24, 2005 - 7:53 am UTC

I misunderstood the documenation ?

what does
<quote src=</code> http://oraclesvca2.oracle.com/docs/cd/B10501_01/server.920/a96540/queries4a.htm#2053976 > <code>
6. Oracle returns the rows in the order shown in Figure 8-1. In the diagram, children appear below their parents. For an explanation of hierarchical trees, see Figure 2-1, "Hierarchical Tree".
</quote>

mean ?

I would say, since we don't have siblings here, and children
appear below their parents, and we select only level, we'll get the numbers
1
2
3
4
5
6
...
:b

in the order God made them

Do I miss something or misunderstand something ?


Tom Kyte
June 24, 2005 - 7:58 am UTC

children appear below their parents.

period. nothing about the ordering of the children below their parents, nothing about the ordering of the parents.

Just "parent, followed by child, in some order"


It does not say "parents are processed in some order", or "child are generated in some order"

Just parents are followed by children.

Arguing a moot point, it is highly likely that the select from dual trick will in fact return them in order, I cannot imagine they would not be, but it is not assured.

Just "parent, followed by child, in some order"

Matthias Rogel, June 24, 2005 - 8:28 am UTC

well, when there are no siblings
(as in the example),
there is only one order possible

Tom Kyte
June 24, 2005 - 12:37 pm UTC

I guess in this specific case, that would be true, yes. since they are all children of the prior row.



List item

John Binny, July 10, 2005 - 6:23 am UTC

Hi Tom
How r U?

I am working in Oracle JDeveloper 10g.
I want to change an item into List Item. How can I?
It's not List Of Values(LOV)

Regards
binny

optomizing your str2tbl function

Jeremy, July 18, 2005 - 5:39 pm UTC

Hey tom, just was looking over your str2tbl and i have two questions...

1. Would you see any benifit to declaring this function deterministic?  I know that this allows you to declare function-based indexes on it and use it in MV's, but could it also affect the plans generated by avoiding repeat runs of the function in the same statement, transaction, or session?

Also, do you think it would hurt anything to use AUTHID CURRENT_USER?

2. This is my REAL question...  how can I optomize the plans generated when using this function in the WHERE clause?  Specifically, it always seems to use a HASH JOIN with the function results.  Is there any way I can get the function to use an INLIST or NESTED_LOOP (because I know that the function returns a very small number of rows compared to the table)?  Or even better - can I get the optomizer to look into the table and choose an appropriate plan based on it's contents?  (For example: NL join if there's 2 rows, HASH if there's 500.)


connect system

create or replace type str2tblType as table of varchar2(30)

create or replace function str2tbl( p_str in varchar2, p_delim in varchar2 
default ',' ) return str2tblType
deterministic authid current_user PIPELINED 
as
    l_str      long default p_str || p_delim;
    l_n        number;
begin
    loop
        l_n := instr( l_str, p_delim );
        exit when (nvl(l_n,0) = 0);
        pipe row( ltrim(rtrim(substr(l_str,1,l_n-1))) );
        l_str := substr( l_str, l_n+1 );
    end loop;
    return;
end;

create public synonym str2tbl for str2tbl;
grant execute on str2tbl to public;



connect scott/tiger

drop table test;
create table test(id primary key, name) as
  select object_id, object_name from all_objects;

SQL> select count(*) from test;

  COUNT(*)
----------
     39027

SQL> explain plan for
  2  select * from test where id in (
  3    10,20,30,40
  4  );

Explained.

SQL> select * from table(dbms_xplan.display);

--------------------------------------------------------------------------------------------
| Id  | Operation                    | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |             |     2 |    60 |     3   (0)| 00:00:01 |
|   1 |  INLIST ITERATOR             |             |       |       |            |          |
|   2 |   TABLE ACCESS BY INDEX ROWID| TEST        |     2 |    60 |     3   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN          | SYS_C005969 |   172 |       |     2   (0)| 00:00:01 |
--------------------------------------------------------------------------------------------

SQL> explain plan for
  2  select * from test where id in (
  3    select * from table(str2tbl('10,20,30,40'))
  4  );

Explained.

SQL> select * from table(dbms_xplan.display);

----------------------------------------------------------------------------------------------
| Id  | Operation                          | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |         |     1 |    32 |    72   (3)| 00:00:01 |
|*  1 |  HASH JOIN RIGHT SEMI              |         |     1 |    32 |    72   (3)| 00:00:01 |
|   2 |   COLLECTION ITERATOR PICKLER FETCH| STR2TBL |       |       |            |          |
|   3 |   TABLE ACCESS FULL                | TEST    | 42966 |  1258K|    47   (3)| 00:00:01 |
----------------------------------------------------------------------------------------------
 

Tom Kyte
July 18, 2005 - 6:40 pm UTC

1) deterministic will not affect its performance.

deterministic will not cause the OPTIMIZER to call it differently, only lets it be used in function based indexes and such.

2)
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:3779680732446#15740265481549 <code>

deterministic functions

lh, July 19, 2005 - 3:04 am UTC

Tom Kyte
July 19, 2005 - 7:34 am UTC

it only happens with mv's and fbi's.

it has never yet happened with just "select * from t where unindexed_col = f()"


rownum>=0 in 10g

Jeremy, July 19, 2005 - 2:44 pm UTC

Oops, now I'm the dolt who forgets to do a search before submitting a question.  Thanks for the gracious link instead of just saying "RTFM"...  ;)  Although I also think it'll be helpful to have the link posted on this question.

On a side note, I don't seem to need the "rownum>=0" for my example on 10g...

SQL> explain plan for
  2  select * from test where id in (
  3    select * from table(str2tbl('10,20,30,40'))
  4  );

Explained.

SQL> select * from table(dbms_xplan.display);

----------------------------------------------------------------------------------------------
| Id  | Operation                          | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |         |     1 |    32 |    72   (3)| 00:00:01 |
|*  1 |  HASH JOIN RIGHT SEMI              |         |     1 |    32 |    72   (3)| 00:00:01 |
|   2 |   COLLECTION ITERATOR PICKLER FETCH| STR2TBL |       |       |            |          |
|   3 |   TABLE ACCESS FULL                | TEST    | 39027 |  1143K|    47   (3)| 00:00:01 |
----------------------------------------------------------------------------------------------

SQL> explain plan for
  2  select * from test where id in (
  3    select /*+cardinality(t 10)*/ * from table(str2tbl('10,20,30,40')) t
  4  );

Explained.

SQL> select * from table(dbms_xplan.display);

---------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |             |    10 |   320 |    30   (4)| 00:00:01 |
|   1 |  NESTED LOOPS                       |             |    10 |   320 |    30   (4)| 00:00:01 |
|   2 |   SORT UNIQUE                       |             |       |       |            |          |
|   3 |    COLLECTION ITERATOR PICKLER FETCH| STR2TBL     |       |       |            |          |
|   4 |   TABLE ACCESS BY INDEX ROWID       | TEST        |     1 |    30 |     1   (0)| 00:00:01 |
|*  5 |    INDEX UNIQUE SCAN                | SYS_C005969 |     1 |       |     0   (0)| 00:00:01 |
---------------------------------------------------------------------------------------------------
 

Tom Kyte
July 19, 2005 - 5:38 pm UTC

i like the rownum > 0 just to "materialize" the collection into temp, to avoid plsql from being invoked more than once.

rownum>=0 in 10g

Jeremy, July 20, 2005 - 12:31 pm UTC

Hey Tom...

I'm really scratching my head on this one.  First of all, in 10g this "rownum>=0" doesn't seem to force the CBO to materialize as a view (see below - in fact the behavior seems to be the opposite in 10g).  Secondly, from your example I'm almost dead positive that the reason STR2TBL was called 18051 times wasn't because it wasn't materialized, but because it was the outer rowsource in a nested loop join.  If you had a full table scan as the outer table then that scan would happen 18051 times too, wouldn't it?

Were you on 9i when you did that example?  Why it picked a Nested Loop Join instead of a Hash Join (which is what 10g does) is beyond me...

I tried a few things with the example from your previous link, and it really looks to me like there is no benifit to the rownum>=0 <b>in 10g</b>.  In fact it seems to make things worse.


SQL> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.1.0.3.0 - Prod
PL/SQL Release 10.1.0.3.0 - Production
CORE    10.1.0.3.0      Production
TNS for 32-bit Windows: Version 10.1.0.3.0 - Production
NLSRTL Version 10.1.0.3.0 - Production

SQL> create or replace type str2tblType as table of varchar2(30);
  2  /

Type created.

SQL> create or replace
  2  function str2tbl( p_str in varchar2, p_delim in varchar2
  3  default ',' ) return str2tblType
  4  deterministic authid current_user PIPELINED
  5  as
  6    l_str      long default p_str || p_delim;
  7    l_n        number;
  8  begin
  9    dbms_application_info.set_client_info( userenv('client_info')+1 );
 10    loop
 11      l_n := instr( l_str, p_delim );
 12      exit when (nvl(l_n,0) = 0);
 13      pipe row( ltrim(rtrim(substr(l_str,1,l_n-1))) );
 14      l_str := substr( l_str, l_n+1 );
 15    end loop;
 16    return;
 17  end;
 18  /

Function created.



SQL> drop table emp2;

Table dropped.

SQL> create table emp2 as
  2  select object_name ename, max(object_id) empno, max(object_type) ot,
  3    max(created) created, rpad( '*', 80, '*') data
  4  from all_objects
  5  group by object_name;

SQL> alter table emp2 add constraint emp2_pk primary key(empno);

Table altered.

SQL> create index emp2_ename on emp2(ename);

Index created.

SQL> analyze table emp2 compute statistics for table for all indexes for all indexed columns;

Table analyzed.

SQL> variable in_list varchar2(255)
SQL> exec :in_list := 'DBMS_PIPE,DBMS_OUTPUT,UTL_FILE';

PL/SQL procedure successfully completed.

SQL> exec dbms_application_info.set_client_info(0);

PL/SQL procedure successfully completed.

SQL> set autotrace traceonly;
SQL> select * from emp2
  2  where ename in (
  3    select /*+ cardinality(t 10 ) */ * from TABLE(cast( str2tbl( :in_list ) as str2tblType) ) t
  4    where rownum >= 0 
  5  );


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=465417 Card=1 Byte
          s=91)

   1    0   FILTER
   2    1     TABLE ACCESS (FULL) OF 'EMP2' (TABLE) (Cost=94 Card=2177
          8 Bytes=1981798)

   3    1     FILTER
   4    3       COUNT
   5    4         FILTER
   6    5           COLLECTION ITERATOR (PICKLER FETCH) OF 'STR2TBL'




Statistics
----------------------------------------------------------
        113  recursive calls
          0  db block gets
        441  consistent gets
          0  physical reads
          0  redo size
        786  bytes sent via SQL*Net to client
        508  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          3  rows processed

SQL> set autotrace off
SQL> select userenv('CLIENT_INFO') from dual;

USERENV('CLIENT_INFO')
----------------------------------------------------------------
21781

SQL> select count(*) from emp2;

  COUNT(*)
----------
     21781



<b>Hey!!  Appears to me that 10g is doing the opposite of your previous example!  It runs the procedure for every row and it does not seem to "materialize" the collection</b> - if by "materialize" you mean "VIEW OF 'VW_NSO_1' (Cost=17 Card=10 Bytes=170))"

Let's see what happens if I take out the "rownum>=0"...



SQL> exec dbms_application_info.set_client_info(0);

PL/SQL procedure successfully completed.

SQL> set autotrace traceonly;
SQL> select * from emp2
  2  where ename in (
  3    select /*+ cardinality(t 10 ) */ * from TABLE(cast( str2tbl( :in_list ) as str2tblType) ) t
  4  );


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=35 Card=10 Bytes=9
          30)

   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'EMP2' (TABLE) (Cost=2 Ca
          rd=1 Bytes=91)

   2    1     NESTED LOOPS (Cost=35 Card=10 Bytes=930)
   3    2       SORT (UNIQUE)
   4    3         COLLECTION ITERATOR (PICKLER FETCH) OF 'STR2TBL'
   5    2       INDEX (RANGE SCAN) OF 'EMP2_ENAME' (INDEX) (Cost=1 Car
          d=1)





Statistics
----------------------------------------------------------
         11  recursive calls
          0  db block gets
         24  consistent gets
          0  physical reads
          0  redo size
        790  bytes sent via SQL*Net to client
        508  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          3  rows processed

SQL> set autotrace off
SQL> select userenv('CLIENT_INFO') from dual;

USERENV('CLIENT_INFO')
----------------------------------------------------------------
1



In 10g, at least, it seems to me that it would not be good to have the rownum in there.

When I get a chance I'll check out 9i, but I'm betting that the "VIEW" collection materialization isn't affecting how many times the procedure gets run so much as the plan -- maybe by materializing the subquery you made the CBO suddenly listen to the hint you have it and put the function on the inside of the nested loop.  I wonder if putting the CARDINALITY hint in the main query block instead of the subquery would make it work without the rownum clause?

Anyway, FWIW this is what I've come up with so far...
 

rownum>=0 in 10g

Jeremy, July 20, 2005 - 12:35 pm UTC

FWIW = For What It's Worth

dangit, i just can't win

;)


Explode a column

VA, July 21, 2005 - 10:58 am UTC

Suppose I have a table like

create table t
(
pk int primary key,
csv varchar2(100)
);
insert into t values (1,'a,b,c');
insert into t values (2,'x,y,z');

Using the techniques described on this page, is there a way I can create a view on this table that "normalizes" the table i.e. puts each of the values in the list on its own row. So if I have this view v, I would do

select ... from v where pk=1

and I would get back 3 rows
1,a
1,b
1,b

Thanks

Tom Kyte
July 21, 2005 - 4:31 pm UTC

ops$tkyte@ORA9IR2> create or replace type str2tblType as table of varchar2(30)
  2  /
 
Type created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace function str2tbl( p_str in varchar2, p_delim in varchar2 default ',' ) return str2tblType
  2  PIPELINED
  3  as
  4      l_str      long default p_str || p_delim;
  5      l_n        number;
  6  begin
  7      loop
  8          l_n := instr( l_str, p_delim );
  9          exit when (nvl(l_n,0) = 0);
 10          pipe row( ltrim(rtrim(substr(l_str,1,l_n-1))) );
 11          l_str := substr( l_str, l_n+1 );
 12      end loop;
 13      return;
 14  end;
 15  /
 
Function created.
 
ops$tkyte@ORA9IR2> select * from t, table(str2tbl(t.csv)) where pk = 1;
 
        PK CSV        COLUMN_VALUE
---------- ---------- ------------------------------
         1 a,b,c      a
         1 a,b,c      b
         1 a,b,c      c


ops$tkyte@ORA9IR2> create or replace view v as
  2  select * from t, table(str2tbl(t.csv)) where pk = 1;
 
View created.
 
ops$tkyte@ORA9IR2> select * from v where pk = 1;
 
        PK CSV        COLUMN_VALUE
---------- ---------- ------------------------------
         1 a,b,c      a
         1 a,b,c      b
         1 a,b,c      c
 
 

Explode a column

A reader, July 21, 2005 - 5:15 pm UTC

Not sure I understand why you changed strtbl to be a pipelined function. Can this be done without using pipelined functions?

Thanks

Tom Kyte
July 21, 2005 - 6:08 pm UTC

sure, but "why"

Explode a column

A reader, July 21, 2005 - 8:06 pm UTC

Well, your original version of str2tbl presented on this site (even for 9iR2) didnt have the "pipelined" and you suddenly added it in response to my question so I was wondering if it was "required" for things to work.

Would this work without the pipelined?

Tom Kyte
July 22, 2005 - 8:40 am UTC

the original would have been with 8i before pipelined functions. With 9i, most, if not all, of the examples would be pipelined.

it is not required, it is preferred and easier.

list of missing items in in list string

wor, July 25, 2005 - 12:15 pm UTC

Hi Tom,

table t1 contains records for 'a' and 'b' in column col1
I have a IN string with values ('a','b','c','d')

I would like to find which values contained in the IN clause are NOT present in the table column col1

e.g. output I want is 'c' and 'd' records
Is this possible ?

Regards,
Wor

Tom Kyte
July 25, 2005 - 1:21 pm UTC

not directly, no. You would need a true "set"

you could use str2tbl

select * from table( cast(str2tbl( :x as thetype) )
where column_value not in ( select col1 from t1 );

where :x := 'a,b,c,d'


Try this

Krishna K, July 25, 2005 - 5:20 pm UTC

lc_str := 'abc~xyz~012';
SELECT count(fksrev) into nCount
FROM SREVSECT
WHERE INSTR(sectno, lc_str) > 0

Tom Kyte
July 25, 2005 - 5:40 pm UTC

if you want to full scan srevsect, that is perfectly acceptable.

here is a variation, not using cast or a function

dnd, September 15, 2005 - 9:51 am UTC

Obviously it assumes comma delimited data.

Connected to Oracle9i Enterprise Edition Release 9.2.0.6.0 

variable mystring varchar2(4000);

begin
:mystring := trim('now,is,the,time,for,all,good,men,to,come,to,the,aid,of,their,country');
end;
/

PL/SQL procedure successfully completed
mystring
---------
now,is,the,time,for,all,good,men,to,come,to,the,aid,of,their,country


SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
  FROM (SELECT comma_location + 1 start_of_string,
               mystring,
               nvl(lead(comma_location, 1) over(ORDER BY comma_location), mystring_length + 1) AS next_comma_location
          FROM (SELECT :mystring mystring,
                       instr(:mystring, ',', LEVEL) comma_location,
                       length(:mystring) mystring_length
                  FROM dual
                CONNECT BY LEVEL < length(:mystring))) v
 WHERE v.start_of_string < v.next_comma_location;

The String
--------------------------------------------------------------------------------
now
is
the
time
for
all
good
men
to
come
to
the
aid
of
their
country

16 rows selected

SQL>  

Tom Kyte
September 15, 2005 - 9:53 am UTC

very nice.

outlines

A reader, September 15, 2005 - 11:03 am UTC

tom:

if i have a query like

select * from emp where
empno in (1,2,4,5);

The query explain plan is correct and comes out effieciently

However if i have a query with a variable inlist
like

select * from emp where
empno in (1,2,3,4,5........100's of empno's) then optimizer
takes a diffenent explain plan.

I want to force an outline for query-11 with query-1 is it possible?


Tom Kyte
September 15, 2005 - 11:51 am UTC

why do you believe the optimizer to be wrong?

from previous review

A reader, September 15, 2005 - 11:12 am UTC

My query is more complex

like

select a.*
from emp a, (other subquery's)
where <join conditions>
and a.empno in (in-list)

Thanks for your help.

Tom Kyte
September 15, 2005 - 11:51 am UTC

same comment.

A reader, September 15, 2005 - 11:58 am UTC

The Optimizer might be right....but i want to see how efficient my query would be when the query-1 explain plan is used. Right now with query-2, i see HASH -JOINS more rampant. With query-1 i see NL's. The IN is resolved using "INLIST ITERATOR"

Rather If i am collecting outline as

SQL>  select 'hello', a.* from user_objects a  where data_object_id in 
  2  (1,
  3  2,
  4  3,
  5  4)
  6  /

no rows selected

SQL>  alter session set create_stored_outlines = false;

Session altered.

SQL> 
SQL> select sql_text from user_outlines;

SQL_TEXT
--------------------------------------------------------------------------------
 select :"SYS_B_0", a.* from user_objects a  where data_object_id in
(:"SYS_B_1",
:"SYS_B_2",
:"SYS_B_3",
:"SYS_B_4")


since outline uses simple text matching if i have variable in list can optimizer use the outline? But one thing that is for sure is when i have a big variable inlist the optimizer takes a different plan.

Thanks, 

Re: Variation for "dnd" ...

Gabe, September 15, 2005 - 12:40 pm UTC

flip@FLOP> variable mystring varchar2(4000);
flip@FLOP>
flip@FLOP> begin
2 :mystring := replace('x,y,z',' ');
3 end;
4 /

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.00
flip@FLOP>
flip@FLOP> col mystring format a20
flip@FLOP> col token format a20
flip@FLOP>
flip@FLOP> SELECT mystring
2 ,'<'||substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string)||'>' token
3 FROM (SELECT comma_location + 1 start_of_string,
4 mystring,
5 nvl(lead(comma_location, 1) over(ORDER BY comma_location),
6 mystring_length + 1) AS next_comma_location
7 FROM (SELECT :mystring mystring,
8 instr(:mystring, ',', LEVEL) comma_location,
9 length(:mystring) mystring_length
10 FROM dual
11 CONNECT BY LEVEL < length(:mystring))) v
12 WHERE v.start_of_string < v.next_comma_location;

MYSTRING TOKEN
-------------------- --------------------
x,y,z <y>
x,y,z <z>

2 rows selected.


dnd variation is awesome!

Prakash, September 15, 2005 - 1:07 pm UTC


A reader, September 15, 2005 - 3:25 pm UTC

Tom,

Not sure whether you have seen this update: else i can post a new question when you are accepting new questions - Thx

The Optimizer might be right....but i want to see how efficient my query would 
be when the query-1 explain plan is used. Right now with query-2, i see HASH 
-JOINS more rampant. With query-1 i see NL's. The IN is resolved using "INLIST 
ITERATOR"

Rather If i am collecting outline as

SQL>  select 'hello', a.* from user_objects a  where data_object_id in 
  2  (1,
  3  2,
  4  3,
  5  4)
  6  /

no rows selected

SQL>  alter session set create_stored_outlines = false;

Session altered.

SQL> 
SQL> select sql_text from user_outlines;

SQL_TEXT
--------------------------------------------------------------------------------
 select :"SYS_B_0", a.* from user_objects a  where data_object_id in
(:"SYS_B_1",
:"SYS_B_2",
:"SYS_B_3",
:"SYS_B_4")


since outline uses simple text matching if i have variable in list can optimizer 
use the outline? But one thing that is for sure is when i have a big variable 
inlist the optimizer takes a different plan.

Thanks, 

 

Tom Kyte
September 15, 2005 - 4:35 pm UTC

well outlines, cursors sharing - ugh.


have you considered a hint for testing purposes?

Faster version

Ajay, September 15, 2005 - 4:48 pm UTC

For larger lists, the following statement is faster

select substr(:mystring,
loc+1,
nvl(
lead(loc) over (order by loc) - loc-1,
length(:mystring) - loc)
)
from (
select distinct (instr(:mystring, ',', 1, level)) loc
from dual
connect by level < length(:mystring)
)

call count cpu elapsed disk query current rows
------- ----- ---- ------- ---- ----- ------- ----
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 28 0.15 0.14 0 0 0 398
------- ----- ---- ------- ---- ----- ------- ----
total 30 0.15 0.14 0 0 0 398


SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
FROM (SELECT comma_location + 1 start_of_string,
mystring,
nvl(lead(comma_location, 1) over(ORDER BY comma_location),
mystring_length + 1) AS next_comma_location
FROM (SELECT :mystring mystring,
instr(:mystring, ',', LEVEL) comma_location,
length(:mystring) mystring_length
FROM dual
CONNECT BY LEVEL < length(:mystring))) v
WHERE v.start_of_string < v.next_comma_location

call count cpu elapsed disk query current rows
------- ----- ---- ------- ---- ----- ------- ----
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.03 0.03 0 0 0 0
Fetch 28 1.35 7.27 3965 0 5 398
------- ----- ---- ------- ---- ----- ------- ----
total 30 1.39 7.30 3965 0 5 398


Re: Ajay

Anders, September 15, 2005 - 5:51 pm UTC

Ajay, you don't need the distinct. Just don't produce anymore rows than you need:
...
CONNECT BY level<=length(:mystring)-length(replace(:mystring, ',', ''))+1)

variation's variation

dnd, September 15, 2005 - 6:27 pm UTC

Much better than mine.

Ajay, September 15, 2005 - 7:16 pm UTC

Very nice, Anders!
And thanks for the compliment, dnd.

Girish, September 16, 2005 - 1:11 am UTC

Hi Tom,

Your answer is good.But is it possible to di without a type definition in a PL/SQL Program

Regds
Girish

Tom Kyte
September 16, 2005 - 8:21 am UTC

if you want to do this without the type - use the sql right above, pipelined functions need a type.

Now, you can do this:


ops$tkyte@ORA9IR2> create or replace package demo_pkg
  2  as
  3          type array is table of number;
  4
  5          function foo return array pipelined;
  6  end;
  7  /
 
Package created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace package body demo_pkg
  2  as
  3
  4  function foo return array
  5  pipelined
  6  is
  7  begin
  8          for i in 1 .. 5
  9          loop
 10                  pipe row (i);
 11          end loop;
 12          return;
 13  end;
 14
 15
 16  end;
 17  /
 
Package body created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select * from table( demo_pkg.foo );
 
COLUMN_VALUE
------------
           1
           2
           3
           4
           5

<b>but don't think you got around anything:</b>
 
OBJECT_TYPE  OBJECT_NAME                    S TABLESPACE_NAME
------------ ------------------------------ - ------------------------------
PACKAGE      DEMO_PKG
 
PACKAGE BODY DEMO_PKG
 
TYPE         SYS_PLSQL_41330_9_1
             SYS_PLSQL_41330_DUMMY_1
 

<b>you have two types created automagically for you in this case, instead of just one</b>

 

Re: Faster version

Gabe, September 16, 2005 - 9:50 am UTC

Ajay,

Your tkprof output suggests you didnÂ’t isolate your test execution very well.
You have a query from dual returning 398 rows that did 3965 physical reads and 5 gets in current mode. There isnÂ’t much in that query to justify the 1.39 of cpu time and 7.30 in elapsed time.

And “dnd” … you still need to fix your query.


Ajay, September 16, 2005 - 11:32 am UTC

Gabe,
I'm not sure I understand what you mean by isolating the tests. Can you elaborate?
To get a clean trace file, these two statements (and setting the value of mystring) were the only statements run in the session.

??

dnd, September 16, 2005 - 12:08 pm UTC

Gabe,

I've taken suggestions for you, Ajay and Anders and applied them to my original version. Its much cleaner and seems to perform well.

So I'm confused, in what manner was/is mine broken?

Sorry I'm being a little dense.

dnd ... it is right above

Gabe, September 16, 2005 - 1:41 pm UTC

The input was 'x,y,z' ... output is:

The String
-----------
y
z

Missing the 'x' row.

thanks

dnd, September 16, 2005 - 2:03 pm UTC

My bad.

From the original.

Connected to Oracle9i Enterprise Edition Release 9.2.0.6.0 

SQL> 
set echo on;
variable mystring varchar2(4000);
begin
:mystring := 'now,is,the,time,for,all,good,men,to,come,to,the,aid,of,their,country';
end;
/

PL/SQL procedure successfully completed
mystring
---------
now,is,the,time,for,all,good,men,to,come,to,the,aid,of,their,country
SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
  FROM (SELECT comma_location + 1 start_of_string,
               mystring,
               nvl(lead(comma_location, 1) over(ORDER BY comma_location), mystring_length + 1) AS next_comma_location
          FROM (SELECT d.mystring,
                       instr(d.mystring, ',', LEVEL) comma_location,
                       length(d.mystring) mystring_length
                  FROM (SELECT :mystring mystring     FROM dual) d
                CONNECT BY LEVEL <= length(d.mystring))) v
 WHERE v.start_of_string < v.next_comma_location;

The String
--------------------------------------------------------------------------------
now
is
the
time
for
all
good
men
to
come
to
the
aid
of
their
country

16 rows selected

And with Gabe's input.

SQL> 

variable mystring varchar2(4000);
begin
:mystring := 'x,y,z';
end;
/

PL/SQL procedure successfully completed
mystring
---------
x,y,z
SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
  FROM (SELECT comma_location + 1 start_of_string,
               mystring,
               nvl(lead(comma_location, 1) over(ORDER BY comma_location), mystring_length + 1) AS next_comma_location
          FROM (SELECT d.mystring,
                       instr(d.mystring, ',', LEVEL) comma_location,
                       length(d.mystring) mystring_length
                  FROM (SELECT :mystring mystring     FROM dual) d
                CONNECT BY LEVEL <= length(d.mystring))) v
 WHERE v.start_of_string < v.next_comma_location;

The String
--------------------------------------------------------------------------------
x
y
z 

oops

dnd, September 16, 2005 - 2:06 pm UTC

CONNECT BY LEVEL < length(d.mystring)
became
CONNECT BY LEVEL <= length(d.mystring)

Tom ... a question for you in there, if not too long ...

Gabe, September 16, 2005 - 3:14 pm UTC

Ajay,

I probably rushed a bit there Â… was thrown off by the large numbers (the diff really). There didnÂ’t seem to be a need for any disk activity.

Indeed for small strings (string of ~67 chars and 16 words) I got:

select substr(:mystring,
loc+1,
nvl(
lead(loc) over (order by loc) - loc-1,
length(:mystring) - loc)
)
from (
select distinct (instr(:mystring, ',', 1, level)) loc
from dual
connect by level < length(:mystring)
)

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 3 0.00 0.00 0 7 0 16
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 5 0.01 0.00 0 7 0 16

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
16 WINDOW SORT
16 VIEW
16 SORT UNIQUE
67 CONNECT BY WITH FILTERING
1 NESTED LOOPS
1 TABLE ACCESS FULL DUAL
1 TABLE ACCESS BY USER ROWID DUAL
1 NESTED LOOPS
1 BUFFER SORT
1 CONNECT BY PUMP
1 FILTER
1 TABLE ACCESS FULL DUAL


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 3 0.00 0.00
SQL*Net message from client 3 0.02 0.04
********************************************************************************

SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
FROM (SELECT comma_location + 1 start_of_string,
mystring,
nvl(lead(comma_location, 1) over(ORDER BY comma_location),
mystring_length + 1) AS next_comma_location
FROM (SELECT :mystring mystring,
instr(:mystring, ',', LEVEL) comma_location,
length(:mystring) mystring_length
FROM dual
CONNECT BY LEVEL < length(:mystring))) v
WHERE v.start_of_string < v.next_comma_location

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 3 0.00 0.00 0 7 0 16
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 5 0.00 0.00 0 7 0 16

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
16 VIEW
67 WINDOW SORT
67 VIEW
67 CONNECT BY WITH FILTERING
1 NESTED LOOPS
1 TABLE ACCESS FULL OBJ#(222)
1 TABLE ACCESS BY USER ROWID OBJ#(222)
1 NESTED LOOPS
1 BUFFER SORT
1 CONNECT BY PUMP
1 FILTER
1 TABLE ACCESS FULL OBJ#(222)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 3 0.00 0.00
SQL*Net message from client 3 2.81 2.82


For larger strings though there seems to be one sort going to disk and couldnÂ’t understand why (string of ~2068 chars and 480 words):

select substr(:mystring,
loc+1,
nvl(
lead(loc) over (order by loc) - loc-1,
length(:mystring) - loc)
)
from (
select distinct (instr(:mystring, ',', 1, level)) loc
from dual
connect by level < length(:mystring)
)

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.01 0.00 0 0 0 0
Fetch 33 0.03 0.05 0 7 0 480
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 35 0.04 0.05 0 7 0 480

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
480 WINDOW SORT
480 VIEW
480 SORT UNIQUE
2068 CONNECT BY WITH FILTERING
1 NESTED LOOPS
1 TABLE ACCESS FULL DUAL
1 TABLE ACCESS BY USER ROWID DUAL
1 NESTED LOOPS
1 BUFFER SORT
1 CONNECT BY PUMP
1 FILTER
1 TABLE ACCESS FULL DUAL


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net more data from client 1 0.00 0.00
SQL*Net message to client 33 0.00 0.00
SQL*Net message from client 33 5.64 5.97
********************************************************************************

SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
FROM (SELECT comma_location + 1 start_of_string,
mystring,
nvl(lead(comma_location, 1) over(ORDER BY comma_location),
mystring_length + 1) AS next_comma_location
FROM (SELECT :mystring mystring,
instr(:mystring, ',', LEVEL) comma_location,
length(:mystring) mystring_length
FROM dual
CONNECT BY LEVEL < length(:mystring))) v
WHERE v.start_of_string < v.next_comma_location

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 33 0.26 3.94 1381 7 5 480
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 35 0.26 3.95 1381 7 5 480

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
480 VIEW
2068 WINDOW SORT
2068 VIEW
2068 CONNECT BY WITH FILTERING
1 NESTED LOOPS
1 TABLE ACCESS FULL OBJ#(222)
1 TABLE ACCESS BY USER ROWID OBJ#(222)
1 NESTED LOOPS
1 BUFFER SORT
1 CONNECT BY PUMP
1 FILTER
1 TABLE ACCESS FULL OBJ#(222)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net more data from client 1 0.00 0.00
SQL*Net message to client 33 0.00 0.00
direct path write 4 0.00 0.00
direct path read 674 1.20 2.73
SQL*Net message from client 33 4.66 5.32


So Ajay, your numbers were fine Â… but why is it so?

Playing with the arraysize didnÂ’t help. My explanation is that one of the inline view gets materialized and goes to disk. (?!?!)

Tom, if this is not too long to follow, Â… would you be able to comment?

Here is something interesting (for me, at least) … if I don’t let the “mystring” to flow out of the innermost inline view then all that unscalable behavior goes away (string of ~2000 chars and 464 words, arraysize=500):

select substr(:mystring,
loc+1,
nvl(
lead(loc) over (order by loc) - loc-1,
length(:mystring) - loc)
)
from (
select distinct (instr(:mystring, ',', 1, level)) loc
from dual
connect by level < length(:mystring)
)

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.04 0.03 0 7 0 464
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.04 0.04 0 7 0 464

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
464 WINDOW SORT
464 VIEW
464 SORT UNIQUE
1999 CONNECT BY WITH FILTERING
1 NESTED LOOPS
1 TABLE ACCESS FULL DUAL
1 TABLE ACCESS BY USER ROWID DUAL
1 NESTED LOOPS
1 BUFFER SORT
1 CONNECT BY PUMP
1 FILTER
1 TABLE ACCESS FULL DUAL


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net more data from client 1 0.00 0.00
SQL*Net message to client 2 0.00 0.00
SQL*Net message from client 2 0.12 0.12
SQL*Net more data to client 2 0.00 0.00
********************************************************************************

SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
FROM (SELECT comma_location + 1 start_of_string,
mystring,
nvl(lead(comma_location, 1) over(ORDER BY comma_location),
mystring_length + 1) AS next_comma_location
FROM (SELECT :mystring mystring,
instr(:mystring, ',', LEVEL) comma_location,
length(:mystring) mystring_length
FROM dual
CONNECT BY LEVEL < length(:mystring))) v
WHERE v.start_of_string < v.next_comma_location

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.20 4.43 1002 7 5 464
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.20 4.44 1002 7 5 464

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
464 VIEW
1999 WINDOW SORT
1999 VIEW
1999 CONNECT BY WITH FILTERING
1 NESTED LOOPS
1 TABLE ACCESS FULL DUAL
1 TABLE ACCESS BY USER ROWID DUAL
1 NESTED LOOPS
1 BUFFER SORT
1 CONNECT BY PUMP
1 FILTER
1 TABLE ACCESS FULL DUAL


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net more data from client 1 0.00 0.00
SQL*Net message to client 2 0.00 0.00
direct path write 4 0.00 0.00
direct path read 499 0.18 0.70
SQL*Net message from client 2 0.11 0.12
SQL*Net more data to client 2 0.00 0.00
********************************************************************************

SELECT substr(v.mystring, v.start_of_string, v.next_comma_location - v.start_of_string) "The String"
FROM (SELECT comma_location + 1 start_of_string,
:mystring mystring, ------------ changed here
nvl(lead(comma_location, 1) over(ORDER BY comma_location),
mystring_length + 1) AS next_comma_location
FROM (SELECT --:mystring mystring, ---------- and here
instr(:mystring, ',', LEVEL) comma_location,
length(:mystring) mystring_length
FROM dual
CONNECT BY LEVEL < length(:mystring))) v
WHERE v.start_of_string < v.next_comma_location

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.01 0.01 0 7 0 464
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.01 0.01 0 7 0 464

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
464 VIEW
1999 WINDOW SORT
1999 VIEW
1999 CONNECT BY WITH FILTERING
1 NESTED LOOPS
1 TABLE ACCESS FULL OBJ#(222)
1 TABLE ACCESS BY USER ROWID OBJ#(222)
1 NESTED LOOPS
1 BUFFER SORT
1 CONNECT BY PUMP
1 FILTER
1 TABLE ACCESS FULL OBJ#(222)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net more data from client 1 0.00 0.00
SQL*Net message to client 2 0.00 0.00
SQL*Net message from client 2 9.20 9.21
SQL*Net more data to client 2 0.00 0.00

Thanks.


Tom Kyte
September 16, 2005 - 3:26 pm UTC

well, by not associating the 2000 characters with each 2000 rows you retrieved from the inline view -- it was not "big", so it did not go to disk.


optimization for you...

replace:

ONNECT BY LEVEL < length(:mystring)

with

connect by level <= (length(:mystring)-length(replace(:mystring,',','')))

just get the number of commas in the string.

Missed 1 in the connect by clause

Frank Zhou, September 16, 2005 - 3:47 pm UTC

Change
connect by level <= (length(:mystring)-length(replace(:mystring,',','')))
to
connect by level <= (length(:mystring)-length(replace(:mystring,',','')) + 1)


Tom Kyte
September 16, 2005 - 3:54 pm UTC

indeed - no trailing delimiter! forgot about that, thanks

Inoffensive-looking change Â… so big of a difference.

Gabe, September 16, 2005 - 4:31 pm UTC

So, it is the materialization that makes all the [un-scalable] difference Â…

1: <quote>by not associating the 2000 characters with each 2000 rows</quote>
Would that bind variable be estimated as 2000 bytes or the max of 4000 bytes?

2: Is there a predictable threshold for when the materialization would start happening? Can it be influenced?

3: Autotrace shows a sort to disk, the tracefile shows these direct path writes/reads Â… is there anything else to indicate a materialization took place?


Tom Kyte
September 16, 2005 - 6:08 pm UTC

wasn't the bind 2000 bytes? 1999 rows?

sort sizes should influence that.


The materialization always took place - you just did it in ram other times.


the "view" step indicates it is possible.

having trouble with sql performance

Shawn Brockway, December 21, 2005 - 8:45 am UTC

I have written a pipe lined function to perform a variable in list that is essentially the same as what is listed in this thread. However, when I use my inlist function instead of hardcoding a list of values, I am having trouble getting the sql to range scan an index instead of fast full scanning the index or simply performing a tablescan. I have put together a small test case that appears below.

create table my_objects as
select * from dba_objects;

create index my_objects_idx on my_objects(object_id);

analyze table my_objects compute statistics;

set autotrace on;

select object_name from my_objects
where object_id in (1,5,9);

OBJECT_NAME
--------------
CLU$
I_FILE#_BLOCK#

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=4 Card=3 Bytes=72)
1 0 INLIST ITERATOR
2 1 TABLE ACCESS (BY INDEX ROWID) OF 'MY_OBJECTS' (Cost=4 Card=3 Bytes=72)
3 2 INDEX (RANGE SCAN) OF 'MY_OBJECTS_IDX' (NON-UNIQUE) (Cost=2 Card=3)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
9 consistent gets
0 physical reads
0 redo size
563 bytes sent via SQL*Net to client
652 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
2 rows processed

select object_name
from my_objects mo,
(select column_value as obj_id
from table( in_list_pipe_char('1,5,9'))) inlist
where mo.object_id = inlist.obj_id;

OBJECT_NAME
-----------------
CLU$
I_FILE#_BLOCK#

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=183 Card=8172 Bytes= 212472)
1 0 HASH JOIN (Cost=183 Card=8172 Bytes=212472)
2 1 COLLECTION ITERATOR (PICKLER FETCH) OF 'IN_LIST_PIPE_CHAR'
3 1 TABLE ACCESS (FULL) OF 'MY_OBJECTS' (Cost=163 Card=77788 Bytes=1866912)

Statistics
----------------------------------------------------------
211 recursive calls
0 db block gets
1174 consistent gets
0 physical reads
0 redo size
563 bytes sent via SQL*Net to client
652 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
6 sorts (memory)
0 sorts (disk)
2 rows processed

Any thoughts on how I can get the two sql statements to behave similarly? I'll have a hard time getting developers to use bind variables for in-lists if I can't improve the performance of this method using bind variables.

Thanks,
Shawn

Tom Kyte
December 21, 2005 - 7:25 pm UTC

As Always...

Shawn Brockway, December 22, 2005 - 9:18 am UTC

Tom you are the man! I added the cardinality hint and a rownum >= 0 into my query and the execution plans matched. When I applied this to a true application scenario for demonstration purposes, my version ran nearly 8X faster. You just have to love those bind variables.

Happy Holidays Tom.

Thanks,
Shawn

what if huge list

Steve, February 07, 2006 - 11:53 am UTC

Hi Tom,

If I have a huge list, say 2000 items, the way
cast(in_list(...)) is still a effective way?
and what is the length limitation of the IN Clause?

Thanks!



Tom Kyte
February 08, 2006 - 1:32 am UTC

well, you will hit the 4000 byte limit for binding varchar2's in SQL - since you have 1999 commas to consider!

At that point, I'd likely be opting for a global temporary table with representative stats set on it.

create global temporary table in_list( x int );
exec dbms_stats.set_table_stats( user, 'IN_LIST', numrows => 2000 );

(since we'll assume for this example that 2000 is the "average" number of rows)


then you would array insert the in list values into the table (which you might have to delete from first depending on how you use it) and just say where in that table

JDBC and Variable "In List"

Su Baba, February 27, 2006 - 9:41 pm UTC

How do I use a variable "in list" in JDBC?

Tom Kyte
February 28, 2006 - 7:03 am UTC

the same way I did in sqlplus? Why would it be any different?

INTERSECTION of many stored QUERIES

Sah, March 21, 2006 - 3:11 pm UTC

create table t (Id number, query varchar2(4000));
insert into t values (1, 'select vend_seqno from vendors');
insert into t values (2, 'select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000');
insert into t values (3, 'select vnjc_vend_seqno from vendor_job_commodity_assigns where vnjc_bjob_jobnumber = ''J29990''')

select * from t;
ID SUBSTR(QUERY,1,100)
---------------- ----------------------------------------------------------------------------------------------------
1 select vend_seqno from vendors
2 select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000
3 select vnjc_vend_seqno from vendor_job_commodity_assigns where vnjc_bjob_jobnumber = 'J29990'

Tom,

Thanks for the excellent site!
-----------------------------------------------------------
I want to write a procedure that will do an intersection of all the stored queries in table t. The procedure will return the resultant COUNT of seqnos(in the given example case it will count of vend_seqnos). It will be something like:

select count(*) from
(
select vend_seqno from vendors
intersect
select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000
intersect
select vnjc_vend_seqno from vendor_job_commodity_assigns where vnjc_bjob_jobnumber = 'J29990'
);
----------------------------------------------------------
Another procedure will get the actual seqnos and store them in an actual table. It will be something like:

select vend_seqno from vendors
intersect
select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000
intersect
select vnjc_vend_seqno from vendor_job_commodity_assigns where vnjc_bjob_jobnumber = 'J29990';
-----------------------------------------------------------
The problem is the above concatenated sqlstring can become more than 32000 characters(in real world examples) and pl/sql will not be able to handle that. Is it possible to execute this query in chunks of 32000 characters and store the results in a temp table or something similar? But how do I define the chunks? The query field in table t can be 4000 characters! Kindly suggest an efficient way to do this.

Please advise. Thanks.

Tom Kyte
March 22, 2006 - 2:48 pm UTC

ugh, WHY WHY WHY would you do that.

Let the other guy do the insert and TELL YOU how many it did.

do not, repeat, do not even consider thinking about counting them. Especially since there is nothing preventing you from modifying the data between the count and the insert - so the count is sort of bogus, meaningless, waster of time.

this also just a bad looking idea in general - you have so many queries in strings in a table without any bind variables - and they are >32k in size. geez.

dbms_sql can use a plsql index by table of strings and that can exceed 32k. I won't demo it, I'm opposed to this idea - but that is what you can use.

but don't count, that would just be wrong.

Intersection of queries

Sah, March 23, 2006 - 6:20 pm UTC

Tom,

Thanks for the reply. This is for an 'Advanced Search' application being developed. User selects some parameters on screen and the resultant sql-query is passed to stored procedure to be stored in the database. Then the same user selects another criteria and this also gets stored...and so on. They promise each time query passed as parameter will be less than 32k (but ofcource if I concatenate all the stored queries in a stored procedure then it'll be > 32k). So they want all these queries to be stored and intersection of all these queries to be done by database procedures and a count returnd.

We're not inserting records, but only searching i.e. doing selects. (The inserts I wrote were to show sample data in the table and just for the purpose so that you could replicate the scenario easily please). Actually, the users want those queries to be inserted in the table by the stored procedure. The application users opine that this is a very dynamic meathod -- since you're storing queries, so the count done at any time will be at that point of time. (Earlier we were thinking of storing the resultant seqnos as comma delimited CLOB instead of the queries -- but that didn't work out because the search on millions of seqnos as a CLOB was very slow, even after using context index)

They want two procedures like the following:
FIRST PROCEDURE:
****************
PROCEDURE update_cache (
Id IN NUMBER,
sqlstr IN VARCHAR2,
seqno_count OUT NUMBER
);

Following is an example of how the procedure will be used:
____________________________________________________________________
declare
l_count number;
begin
update_cache(1,'select vend_seqno from vendors',l_count);
dbms_output.put_line('l_count='||l_count);
end;
l_count=100
-- here l_count is the count of intersection of queries at Id <=1


select * from t;
ID SUBSTR(QUERY,1,100)
-------------------------
1 select vend_seqno from vendors
____________________________________________________________________
declare
l_count number;
begin
update_cache(2,'select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000',l_count);
dbms_output.put_line('l_count='||l_count);
end;
l_count=60
-- here l_count is the count of intersection of queries at Id <=2

select * from t;
ID SUBSTR(QUERY,1,100)
-------------------------
1 select vend_seqno from vendors
2 select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000
____________________________________________________________________
declare
l_count number;
begin
update_cache(3,'vnjc_vend_seqno from vendor_job_commodity_assigns where vnjc_bjob_jobnumber = ''J29990''',l_count);
dbms_output.put_line('l_count='||l_count);
end;
l_count=20
-- here l_count is the count of intersection of queries at Id <=3


select * from t;
ID SUBSTR(QUERY,1,100)
-------------------------
1 select vend_seqno from vendors
2 select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000
3 select vnjc_vend_seqno from vendor_job_commodity_assigns where vnjc_bjob_jobnumber = 'J29990'
____________________________________________________________________

Note: ID is just a sequence number and is PK of the table t.


SECOND PROCEDURE:
*****************

TYPE rc IS REF CURSOR;

FUNCTION get_results (
sqlfilter IN VARCHAR2,
) RETURN rc;


sqlfilter is a sql query passed in from the application in following format. It is kind of a basic filter.
SELECT ..
FROM..
WHERE..
AND..

They want me to concatenate the advanced search query to this sqlfilter as following:
SELECT ..
FROM..
WHERE..
AND..
-- advanced search results
AND vend_seqno IN
(
select vend_seqno from vendors
intersect
select vnlo_vend_seqno from vendor_locations where vnlo_seqno > 4000
intersect
select vnjc_vend_seqno from vendor_job_commodity_assigns where
vnjc_bjob_jobnumber = 'J29990'
);

They then want the resultant vend_seqnos to be stored in a database table. This database table will be used by Crystal Reports for reporting purposes.

Kindly advise how can I cater to the user requirements.

Tom Kyte
March 24, 2006 - 8:18 am UTC

No binds, no look - this is a "not good implementation". Not only for the obvious sql injection issues - but the scalability of this is going no where.


but i did tell you how to parse a string >32k right above if you really want to follow this path

A reader, March 24, 2006 - 12:16 pm UTC

Hi Tom,

I have the following requirement. I have a table t with structure as follows:

create table t
(
id number,
col1 varchar2(255),
col2 varchar2(255),
col3 varchar2(255)
);

insert into t values (1, 'Value for col1', null, null);
insert into t values (2, 'Value for col1', 'Value for col2', null);
insert into t values (3, null, 'Value for col2', 'Value for col3');
insert into t values (4, 'Value for col2', null, 'Value for col3');
insert into t values (5, 'Value for col3', null, 'Value for col1');
commit;

I have my procedure as follows:

create or replace package retidpack as
TYPE rc is ref cursor;
procedure retid
(
pcol1 in varchar2 default NULL,
pcol2 in varchar2 default NULL,
pcol3 in varchar2 default NULL,
rcurs out rc
);
end;
/

create or replace package body retidpack as
procedure retid
(
pcol1 in varchar2 default NULL,
pcol2 in varchar2 default NULL,
pcol3 in varchar2 default NULL,
rcurs out rc
)
is
sel varchar2(20);
whcl varchar2(100);
qry varchar2(200);

begin
sel := ' select id from t ';
whcl := ' where 1 = 1 ';

if (pcol1 is not null) then
whcl := whcl || ' and col1 = :pcol1 ';
end if;
if (pcol2 is not null) then
whcl := whcl || ' and col2 = :pcol2 ';
end if;
if (pcol3 is not null) then
whcl := whcl || ' and col3 = :pcol3 ';
end if;

qry:= sel || whcl;

open rcurs for qry using in pcol1;

end;
end retidpack;
/

Now when I execute my package I get

exec retidpack.retid ('Value for col1', null, null, :rc);

PL/SQL procedure successfully completed.


ID
----------
1
2

Now if you go back to my insert statements in the last one, I have assigned the value of col3 as 'Value for col1'. In my current setup that is not possible because I am comparing pcol1 with col1, pcol2 with col2 and pcol3 with col3. Is there any way that I can change this a little bit such that I will only get one input parameter pcol and I should compare it against col1, col2 and col3 and return all matches so that when I execute my procedure I should 1, 2 and 5 as the results rather than just 1 and 2.

Thanks.

Tom Kyte
March 24, 2006 - 3:36 pm UTC

static sql with

where col1 = pcol1 or col2 = pcol1 or col3 = pcol3;


seems very staightforward? You are asking the entirely wrong question of this data it seems.

A reader, March 24, 2006 - 4:17 pm UTC

I am sorry, I did not follow you. Are you asking me a question?

Tom Kyte
March 24, 2006 - 5:34 pm UTC

I'm saying - it looks pretty straight forward, you are using the wrong predicate, you really want to search all three columns according to what you are saying.

To be sure

Carl Bruneau, April 10, 2006 - 12:20 pm UTC

Hello Thomas,

I read this thread but there is some things I am not sure to understand.

First of all: Is the goal of myTableType and in_list() is to be able to have one "generic" statement (with one bind variable) no matter how we will call this qery in the futur (the number of element in the INLIST)?

Because if we don't use this approach we will have as many statement in the shared pool as we have possible combinations of element in the INLIST, rigth? And it will not scale at all, rigth?

Best regards,

Carl


Tom Kyte
April 11, 2006 - 10:53 am UTC

in_list is a function that takes a delimited string of N (n is not known) elements and returns them one by one. So, you can call this function with 1, 2, 3, ... N elements and it'll return them. That is the goal - yes, like you described.


Else, you'll end up hard parsing like mad since every in list with a different number of values or just different values will be a new, unique SQL statement.

One hard parse

Carl Bruneau, April 11, 2006 - 9:16 am UTC

Hello Thomas,

I finally verified and the answer seems to be Yes.

I traced many execution of the same generic statement:

SQL> select /*+ FIRST_ROWS */ * 
  2  from street 
  3  where municip_no in
  4    ( select *  from TABLE( select cast( in_list(:x) as mytableType ) from dual ) );


And in the trace file a have only one hard parse. The other execution not:

select /*+ FIRST_ROWS */ *
from street
where municip_no in
  ( select *  from TABLE( select cast( in_list(:x) as mytableType ) from dual ) )

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          6          0           0
Fetch        1      0.00       0.00          0         10          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        3      0.00       0.00          0         16          0           0

Misses in library cache during parse: 0
Optimizer goal: FIRST_ROWS
Parsing user id: 2273  

Thanks for this great example,

Best regards,

Carl 

THE?????

A reader, May 04, 2006 - 8:38 am UTC

Here is copy/paste from your first reply in this thread.

ops$tkyte@dev8i> select * from all_users where username in
2 ( select *
3 from THE ( select cast( in_list('OPS$TKYTE, SYS, SYSTEM')
as mytableType ) from dual ) )
4 /

I completely didnt understand the 3rd Line.
what is this from THE, "THE", is it a table ,alias
or what?

Thanks


Tom Kyte
May 04, 2006 - 4:31 pm UTC

THE is deprecated syntax from 8.0/early 8.1.5 releases - not necessary anymore.

Recommendation to Oracle

RV, May 04, 2006 - 11:06 pm UTC

I've used Oracle, MS Sql Server and Sybase for a long time and I still prefer to go in the Oracle way in terms of features etc.
The table variable in Sybase(from very early version) and carried to MS Sql Server is very handy for the database programmers. The table variable is just like any other variable type inside a procedure or function and it is easy to define and it is destroyed when the procedure/function call ends. These functionality is available in Oracle in a complex way as explained in this article from Oracle 8 onwards; still it is complex.

Can Oracle create another PL/SQL variable of table type on which all DML statements can be issued in PL/SQL?


Tom Kyte
May 05, 2006 - 1:46 am UTC

what is "complex" about


ops$tkyte@ORA10GR2> declare
  2          l_var myTableType := myTableType();
  3  begin
  4          for x in ( select * from table( l_var ) )
  5          loop
  6                  null;
  7          end loop;
  8  end;
  9  /

PL/SQL procedure successfully completed.

??

but no, you would not apply insert/update/delete to this, to insert you either would assign or bulk collect.  same with update and delete - we can use "select bulk collect into" to 'update' (select modified data) or 'delete' (use a negative where clause)
 

One more trick

_bag_, May 05, 2006 - 6:13 am UTC

var p_object_names varchar2(2000)
/
exec :p_object_names := 'DBA_JOBS, DBA_VIEWS, DBA_TABLES';
/
select * from all_objects
where 0 < instr(
translate('|' || :p_object_names || '|', ' ,;:', '||||')
, '|' || object_name || '|'
)
/


Tom Kyte
May 05, 2006 - 7:13 am UTC

that would be "indexes = false" for that one.

to _bag_

Matthias Rogel, May 05, 2006 - 7:46 am UTC

nice trick anyway !!

truncated in list using SYS_CONTEXT

Tom, May 06, 2006 - 1:15 pm UTC

Hi Tom,

Many thanks for all the excellent examples and great solutions . We are using SYS_CONTEXT to bind a variable IN list with a table function in a dynamic sql that is used for a search. The approach works fine except when the IN list exceeds 255 characters. The list is truncated. When we check the context value(pl/sql) we can see that it is the full list but once the sql is executed the context value gets truncated. I checked the Sql Supplied packages documentation and could not find any limitations on the size of the attribute value in the call to DBMS_SESSION.SET_CONTEXT. As we can see the context holds the correct value(ie, greater than 255 characters) we assume that there is actually no limitation on the attribute value other than it must be a VARCHAR2. Would you be able to explain why the value is truncated when the SQL is executed?

Thanks in advance.

Tom Kyte
May 07, 2006 - 11:24 am UTC

got example to work with please?

examples are SMALL yet COMPLETE.

truncated in list using SYS_CONTEXT

tom, May 08, 2006 - 12:29 pm UTC

here is the example.

CREATE OR REPLACE
TYPE tbl_Number AS TABLE OF NUMBER;
/

CREATE OR REPLACE FUNCTION fn_String_2_table_Numbers(p_String IN VARCHAR2)
RETURN tbl_Number
AS
v_String VARCHAR2(4000) DEFAULT p_String || ',';
v_Pos PLS_INTEGER;
v_TblNumber tbl_Number := tbl_Number();
BEGIN
LOOP
v_Pos := INSTR(v_String,',');
EXIT WHEN (NVL(v_Pos,0) = 0);
v_TblNumber.EXTEND;
v_TblNumber(v_TblNumber.COUNT) := TO_NUMBER(TRIM(SUBSTR(v_String,1,v_Pos - 1)));
v_String := SUBSTR(v_String,v_Pos + 1);
END LOOP;
RETURN v_TblNumber;
END fn_String_2_table_Numbers;
/


CREATE OR REPLACE PACKAGE pkg_context_example
IS

PROCEDURE select_context(
list OUT VARCHAR2
,ret OUT SYS_REFCURSOR);

PROCEDURE print_string(str IN VARCHAR2, strLength IN NUMBER := 80);

END pkg_context_example;
/

CREATE OR REPLACE PACKAGE BODY pkg_context_example
IS
c_CONTEXT_NAME CONSTANT VARCHAR2(30) := 'CTX_PKG_CONTEXT_EXAMPLE';


PROCEDURE print_string(str IN VARCHAR2, strLength IN NUMBER := 80)

IS

v_Length NUMBER(3) := strLength;
v_Str VARCHAR2(32767) := str;

BEGIN

IF strLength > 255 THEN
v_Length := 255;
END IF;

LOOP
DBMS_OUTPUT.PUT_LINE(SUBSTR(v_Str,1,v_Length));
v_Str := SUBSTR(v_Str,v_Length + 1);
EXIT WHEN v_Str IS NULL;
END LOOP;

END print_string;

PROCEDURE print_session_context
IS
context_list DBMS_SESSION.AppCtxTabTyp;
context_size NUMBER;
BEGIN

DBMS_SESSION.LIST_CONTEXT (context_list,context_size);

IF context_list.COUNT > 0 THEN
FOR i IN context_list.FIRST .. context_list.LAST
LOOP
print_string(RPAD('NAMESPACE:' || context_list(i).namespace || ' ATTRIBUTE:' || context_list(i).attribute,75,' ') || ' VALUE:' || context_list(i).VALUE,255);
END LOOP;
END IF;

END print_session_context;

FUNCTION fn_set_context(
p_ContextAttrName IN VARCHAR2
,p_ContextAttrValue IN VARCHAR2)
RETURN VARCHAR2

IS

BEGIN
DBMS_SESSION.SET_CONTEXT(c_CONTEXT_NAME,p_ContextAttrName,p_ContextAttrValue);
RETURN 'SYS_CONTEXT( ''' || c_CONTEXT_NAME || ''' , ''' || p_ContextAttrName || ''' )';

END fn_set_context;


PROCEDURE select_context(
list OUT VARCHAR2
,ret OUT SYS_REFCURSOR)
IS

v_SQL VARCHAR2(32767);
v_InList VARCHAR2(4000);

BEGIN

v_InList := '1002,1003,1004,1005,1006,1007,1008,1009,1011,1013,1014,1015,1016,1017,1018,1019,1020,1021,1022,1023,1024,1025,1026,1027,1028,1029,1030,1031,1032,1033,1034,1035,1036,1037,1038,2001,2003,2006,2009,2015,2016,2017,2018,2020,2029,2030,2031,2032,2034,2036,2037,2038,2039,2040,2041,2042,2043,2044,2045,2046,2047,2048,2049,2051,2052,3001,3002,3003,3004,3005,4001,4002,5001,5002,6001,6002,6003,6004,6005,6006,6007,6008';


v_SQL := 'SELECT ' || fn_set_context('v_InList',v_InList) || ' FROM DUAL';

print_session_context;

EXECUTE IMMEDIATE v_SQL INTO list;

v_SQL := 'SELECT * FROM TABLE (CAST(fn_String_2_table_Numbers(' || fn_set_context('v_InList',v_InList) || ') AS tbl_Number ))';

OPEN ret FOR
v_SQL;

END select_context;

END pkg_context_example;
/


CREATE CONTEXT CTX_PKG_CONTEXT_EXAMPLE USING PKG_CONTEXT_EXAMPLE;
/

SET SERVEROUTPUT ON SIZE 1000000
DECLARE
LIST VARCHAR2(4000);
RET SYS_REFCURSOR;

BEGIN

PKG_CONTEXT_EXAMPLE.SELECT_CONTEXT ( LIST, RET );

pkg_context_example.print_string('LIST = ' || LIST,255);

pkg_context_example.print_string('from cursor');

LOOP
FETCH ret INTO list;
EXIT WHEN ret%NOTFOUND;
pkg_context_example.print_string(list);
END LOOP;

END;

The search that we are using is obviously much more complicated then what is presented above. We have to use dynamic sql as there are 17 fields which the user can search on or any combination of those 17 fields.

When the code is run the session context attribute value is the full string but when the sql is executed the value is truncated at 256 characters.

Thank you for your assistance.

Tom Kyte
May 08, 2006 - 1:35 pm UTC

it is more complex then this? ouch - cause this was pretty complex to follow.

Not sure what I'm looking for here - can you

a) make this smaller
b) tell us how to run
c) tell us precisely what to look for.

Why Can I Not Put Type In Package?

Steve Standish, June 01, 2006 - 11:07 am UTC

Hi Tom,

Hopefully this is a simple mistake or mis-use:

create or replace type myTableType as table of number;
  2  /

Type created.

SQL> 
SQL> create or replace function str2tbl( p_str in varchar2 ) return
  2  myTableType
  3    as
  4        l_str   long default p_str || ',';
  5        l_n        number;
  6        l_data    myTableType := myTabletype();
  7    begin
  8        loop
  9            l_n := instr( l_str, ',' );
 10            exit when (nvl(l_n,0) = 0);
 11            l_data.extend;
 12            l_data( l_data.count ) := ltrim(rtrim(substr(l_str,1,l_n-1)));
 13            l_str := substr( l_str, l_n+1 );
 14        end loop;
 15        return l_data;
 16    end;
 17  /

Function created.

SQL> 
SQL> select * from all_users
  2    where user_id in ( select *
  3      from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as mytableType ) from
  4  dual ) )
  5  /

USERNAME                          USER_ID CREATED                               
------------------------------ ---------- ---------                             
SYSTEM                                  5 24-JUN-05                             

*********************************************
WORKS!!!
*********************************************

SQL> CREATE or replace PACKAGE tmp_define
  2  IS
  3  
  4  type myTableType is table of number;
  5  
  6  END tmp_define;
  7  
  8  /

Package created.

SQL> 
SQL> create or replace function str2tbl( p_str in varchar2 ) return
  2  tmp_define.myTableType
  3    as
  4        l_str   long default p_str || ',';
  5        l_n        number;
  6        l_data    tmp_define.myTableType := tmp_define.myTabletype();
  7    begin
  8        loop
  9            l_n := instr( l_str, ',' );
 10            exit when (nvl(l_n,0) = 0);
 11            l_data.extend;
 12            l_data( l_data.count ) := ltrim(rtrim(substr(l_str,1,l_n-1)));
 13            l_str := substr( l_str, l_n+1 );
 14        end loop;
 15        return l_data;
 16    end;
 17  /

Function created.

SQL> 
SQL> select * from all_users
  2    where user_id in ( select *
  3      from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as tmp_define.mytableType ) from
  4  dual ) )
  5  /
    from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as tmp_define.mytableType ) from
                                                           *
ERROR at line 3:
ORA-00902: invalid datatype 


SQL> 

DOESN'T WORK - Help?
 

Tom Kyte
June 01, 2006 - 11:31 am UTC

because you are using SQL, SQL see's "sql types".

Same problem?

Steve, June 01, 2006 - 12:12 pm UTC

Hi Tom,

thanks for your time.  The intent is to get much more complex code into PL/SQL.  I provided the simplest example of the problem.  Here I get the same problem?

create or replace type myTableType as table of number;
  2  /

Type created.

SQL> 
SQL> create or replace function str2tbl( p_str in varchar2 ) return
  2  myTableType
  3    as
  4        l_str   long default p_str || ',';
  5        l_n        number;
  6        l_data    myTableType := myTabletype();
  7    begin
  8        loop
  9            l_n := instr( l_str, ',' );
 10            exit when (nvl(l_n,0) = 0);
 11            l_data.extend;
 12            l_data( l_data.count ) := ltrim(rtrim(substr(l_str,1,l_n-1)));
 13            l_str := substr( l_str, l_n+1 );
 14        end loop;
 15        return l_data;
 16    end;
 17  /

Function created.

SQL> 
SQL> create or replace function tmp_help return number
  2  as
  3  ln_cnt number;
  4  begin
  5  select count(*) into ln_cnt from all_users
  6    where user_id in ( select *
  7      from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as mytableType ) from
  8  dual ) );
  9  return ln_cnt;
 10  end;
 11  /

Function created.

SQL> CREATE or replace PACKAGE tmp_define
  2  IS
  3  
  4  type myTableType is table of number;
  5  
  6  END tmp_define;
  7  
  8  /

Package created.

SQL> 
SQL> create or replace function str2tbl( p_str in varchar2 ) return
  2  tmp_define.myTableType
  3    as
  4        l_str   long default p_str || ',';
  5        l_n        number;
  6        l_data    tmp_define.myTableType := tmp_define.myTabletype();
  7    begin
  8        loop
  9            l_n := instr( l_str, ',' );
 10            exit when (nvl(l_n,0) = 0);
 11            l_data.extend;
 12            l_data( l_data.count ) := ltrim(rtrim(substr(l_str,1,l_n-1)));
 13            l_str := substr( l_str, l_n+1 );
 14        end loop;
 15        return l_data;
 16    end;
 17  /

Function created.

SQL> create or replace function tmp_help return number
  2  as
  3  ln_cnt number;
  4  begin
  5  select count(*) into ln_cnt from all_users
  6    where user_id in ( select *
  7      from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as tmp_define.myTabletype ) from
  8  dual ) );
  9  return ln_cnt;
 10  end;
 11  /

Warning: Function created with compilation errors.

SQL> show errors
Errors for FUNCTION TMP_HELP:

LINE/COL ERROR                                                                  
-------- -----------------------------------------------------------------      
5/1      PL/SQL: SQL Statement ignored                                          
7/60     PL/SQL: ORA-00902: invalid datatype                                    
SQL> 
 

Tom Kyte
June 01, 2006 - 12:27 pm UTC

you didn't change anything here

You are still using SQL (true, it is embedded in PLSQL) - it is not any different SQL wants SQL types.

Just like you cannot reference "boolean" in SQL. That is a plsql type.

OK, another method?

Steve, June 01, 2006 - 12:51 pm UTC

OK, thanks, I get it now!

Although this original expample is simple my intent was to encapsulate the types into the package (not declare stand alone) so I could make my package types like:

CREATE or replace PACKAGE tmp_define
IS

type myuser_idtbl is table of all_users.user_id%TYPE;

END tmp_define;

Then know my split functions return the same types in table form when passed into SQL statments:

...
where user_id in ( select *
from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as temp_define.myuser_idtbl )
...

This way I wouldn't have alot of standalone "types" sitting around in SQL.

If there is a way to do something like this then great...

Tom Kyte
June 01, 2006 - 1:24 pm UTC

the TYPES must be there, period 

If you want to access them from SQL - even if you get to use the PLSQL type - there are still (more) SQL types created!

ops$tkyte@ORA10GR2> select object_name, object_type from user_objects;

no rows selected

ops$tkyte@ORA10GR2> create or replace package demo_pkg
  2  as
  3          type array is table of number;
  4
  5          function f(n in number) return array pipelined;
  6  end;
  7  /

Package created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> create or replace package body demo_pkg
  2  as
  3
  4  function f(n in number) return array
  5  pipelined
  6  is
  7  begin
  8          for i in 1 .. n
  9          loop
 10                  pipe row(i);
 11          end loop;
 12          return;
 13  end;
 14
 15
 16  end;
 17  /

Package body created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> variable n number
ops$tkyte@ORA10GR2> exec :n := 5;

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR2> select * from table( demo_pkg.f(:n) );

COLUMN_VALUE
------------
           1
           2
           3
           4
           5

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> select object_name, object_type from user_objects;

OBJECT_NAME                    OBJECT_TYPE
------------------------------ -------------------
SYS_PLSQL_66997_9_1            TYPE
DEMO_PKG                       PACKAGE BODY
DEMO_PKG                       PACKAGE
SYS_PLSQL_66997_DUMMY_1        TYPE


Instead of just ONE type - you have two, with really neat names. 

No argument here... Just to clarify

Steve, June 01, 2006 - 1:52 pm UTC

Sorry, I think my statment was not clear:

"... types sitting around in SQL.. "

I understand that anything I create in the database is going somewhere!!!

This is simply a code management approach. For example, we have all of our constants defined in a package and refer to them "constant_pkg_version_1_1.constant_name". This method allows for calling components to change versions when ready.

So, I can write SQL like

"select function_pkg_verion_1_1.myfcn(column, constant_pkg_version_1_1.constant_name) from table"

Simiarly, I would like to contain all type defs in a versioned package as well.

Oracle won't understand a type definition in a package?

Tom Kyte
June 01, 2006 - 2:37 pm UTC

see above?? I just gave an example...



Good Stuff

Steve, June 01, 2006 - 3:29 pm UTC

It works and gives me what I want (see below), thanks.

One (last?) thing - the purpose here is so I can move some code from dynamic SQL to binds.  This type of thing will be incorporated into larger quieries.  Any words of wisdom on performance when using this type of function as part of a larger SQL? For COST there would be no stats on a returning function? In our simple example here could this be a deterministic function?

CREATE or replace PACKAGE tmp_define IS
  2  type user_idtbl is table of all_users.user_id%type;
  3  END tmp_define;
  4  /

Package created.

SQL> 
SQL> create or replace function str2tbl( p_str in varchar2 ) return
  2  tmp_define.user_idtbl pipelined
  3    as
  4        l_str   long default p_str || ',';
  5        l_n        number;
  6    begin
  7        loop
  8            l_n := instr( l_str, ',' );
  9            exit when (nvl(l_n,0) = 0);
 10            pipe row(ltrim(rtrim(substr(l_str,1,l_n-1))));
 11            l_str := substr( l_str, l_n+1 );
 12        end loop;
 13  
 14        return;
 15    end;
 16  /

Function created.

SQL> 
SQL> select * from all_users
  2    where user_id in ( select * from table(str2tbl( '1, 3, 5, 7, 99' )))
  3  /

USERNAME                          USER_ID CREATED                               
------------------------------ ---------- ---------                             
SYSTEM                                  5 24-JUN-05                             

SQL> 
 

Tom Kyte
June 01, 2006 - 4:09 pm UTC

see
</code> https://www.oracle.com/technetwork/issue-archive/2014/14-sep/o54asktom-2279184.html <code>
"query plans with temporary tables"
and make sure to see the next steps set of links as well there.

Excuse me as I have posted the same Qs in different loactions,but this the proper place to post

Indranil, June 02, 2006 - 12:25 am UTC

Hi Tom,

Suppose we have a table like
Create table gs( X NUMBER,Y VARCHAR2(2));

INDRA>select * from gs;

X Y
---------- ------------
1 s1
2 s2

Now,can you please help me for the PL/SQL block below -

INDRA>
declare
v varchar2(3200):='s1,s2'||',';--:control.conditions||',';
sn varchar2(3200);
Type ArrayType Is Table of Varchar2(200)
Index by Binary_integer;
l number;n number;
S ArrayType;
Begin
l:=length(v)-length(replace(v,',',''));
for i in 1..l
loop
n:=instr(v,',',1,1);
s(i):=''''||substr(v,1,n-1)||'''';
v:=substr(v,n+1);
end loop;
For i in 1..l
loop
sn:=sn||','||s(i);
end loop;
sn:=substr(sn,2);
dbms_output.put_line('string= '||sn);
for j in (select x from gs where y in (sn))
loop
dbms_output.put_line('x= '||j.x);
end loop;
End ;
/
string= 's1','s2'

PL/SQL procedure successfully completed.

why the cursor is not able to retrive rows ?
Is it unable to understand the lists in the "in" clause ?

But when we are using sql we get
INDRA>select x from gs where y in ('s1','s2');

X
----------
1
2

Is there any alternative way ?
Note:It was actually a Form 6i Trigger code
for the control item :control.conditions,when
user would enter the conditions like s1,s2,s3,...
and we have to select something from another database
table.

Tom Kyte
June 02, 2006 - 10:25 am UTC

so, look IN THE FIRST PLACE you put it as I hit them in a linear fashion.

(and funny thing, the answer to your question is staring us in the face above as it is the original solution.... hmmm)



how to do this

rahul, August 04, 2006 - 12:38 pm UTC

create or replace procedure get_ename as
Cursor c1 is select ename from scott.emp
where rownum <= 4;
e1 varchar2(100);
e2 varchar2(100);
e3 varchar2(100);
e4 varchar2(100);
begin
for l_rec in C1 LOOP
e1 := l_rec.ename;
e2 := l_rec.ename;
e3 := l_rec.ename;
e4 := l_rec.ename;
END LOOP;
end;

how to assign four differernt enames to foour different variables

Tom Kyte
August 04, 2006 - 12:53 pm UTC

declare
type array is table of emp.ename%type index by binary_integer;
l_emps array;
begin
select ename bulk collect into l_emps from emp where rownum <= 4;

for i in 1 .. l_emps.count
loop
dbms_output.put_line( l_emps(i) );
end loop;
end;


use an array.

rahul, August 04, 2006 - 1:17 pm UTC

but what about the values of e1 e2 e3 e4 how to assign those

thanks a lot
rahul

Tom Kyte
August 04, 2006 - 1:30 pm UTC

one
at
a
time

if you need them in e1, e2, e3, e4 - which would be the wrong way to approach the problem - you would have to assign them

one
at
a
time

suggestion: use the array, lose e1, e2, e3, e4.

Rahul, August 04, 2006 - 1:22 pm UTC

sorry i figured it out

Thanks,
Rahul

rahul, September 14, 2006 - 11:37 pm UTC

declare
e1 varchar2(100);
e2 varchar2(100);
e3 varchar2(100);
e4 varchar2(100);

type array is table of emp.ename%type index by binary_integer;
l_emps array;
begin
select ename bulk collect into l_emps from emp where rownum <= 4;

for i in 1 .. l_emps.count
loop
e1 := ( l_emps(1) );
e2 := ( l_emps(2) );
e3 := ( l_emps(3) );
e4 := ( l_emps(4) );
end loop;
end;


wht happens if there are only 2 employeed in emp table

the pl/sql errors out

how to handle no_data_found

Tom Kyte
September 15, 2006 - 6:54 am UTC

that code is funky - why the loop????

but anyway - you use exceptions blocks to handle...... exceptions

begin
whatever;
exception
when no_data_found then whatever;
end;

Check for existance of Object before proceeding

A reader, September 21, 2006 - 12:35 pm UTC

I have a code which does

for j in << select ...into .. based on condition>>
loop
<<< check for existance of table based on value in into clause of j loop>>

<< do further processing>>
end loop

The problem is it gets 1st value, checks for table and then proceeds and then gets the 2nd value. If the table is not there for the 2nd value, then i just waste time for the 1st processing.

I want to check if objects exists for all values of select clause and if they are, then only proceed to the next.
The logic I had was

for j in << select.... into....condition>>
loop
<< check for objects>>
end loop;

for k in << select.. into...condition>>
<< do further proessing>>
end loop;

Dont know whether above approach is correct because the same select query is written for 2 loops.

Regards,


Tom Kyte
September 22, 2006 - 2:17 am UTC

sorry, but I really don't know what you mean by "it gets the 1st value", "gets the second value" - where is this code getting any values?

you'll need to be a little less hazy on this psuedo code - I didn't quite follow the gist.

A reader, September 22, 2006 - 9:39 am UTC

Apologize for the confusion. I have the following

Source Table SEOSDATA
Backup Tables - SEOSDATA0105, SEOSDATA0205 ..(Basically in the format SEOSDATA<<mmyy>>)

The 1st j loop gets the distinct of mmyy from the SEOSDATA and for each distinct value, it checks whether the corresponding Backup table is present or not. Basically if month is 12 and yr is 04, then you should have a table SEOSDATA1204. Once it finds the table, then it proceeds ahead for doing further validations and insertions.

1) If the j loop does not find a table (eg SEOSDATA0205) already created for mm 02 and yr 05 during the 1st instance of the loop , then it generates exceptions and comes out. What if it does not find the table during the 2nd loop. It would do all the processing, validations for the 1st value in the loop and then proceed for the 2nd value in the loop and then generate exceptions.

2) What would be the logic for checking for existing for tables for all distinct values of mmyy and then only proceed ahead for validations.

Regards

Tom Kyte
September 22, 2006 - 3:26 pm UTC

table<mmyy> ouch, that hurts just to read.. that comment was written before I read the rest - but that hurts.

umm - one word for you: partitioning.

you are sort of on your own for "logic", seems like you'd be able to do this in a single loop, it is JUST code after all??

I say that partially because I don't understand/follow your description in #1.

"then is generates exception and comes out. What if it does not fine the table..."

eh?


I see above two snippets that did not make sense and then an apparent reference to the 2nd snippet (which did not make sense the first time...)

but this sounds like "specify your logic, then CODE your logic just specified"

A reader, September 22, 2006 - 5:43 pm UTC

:( Well it hurts much more because this table is a from a customized application that our client has and unfortunately it is going to remain the same in the near future. So partitioning is ruled out.

1) The requirements are
a) I should get the list of distinct year from my main SEOSDATA table and populate data based on the year 2004 goes to SEOSDATA04 and 2005 goes to SEOSDATA05.

b) The tables will be precreated. Supposing the distinct values for years are 03,04 and 05. So the program should check whether I have table SEOSDATA03,SEOSDATA04, SEOSDATA05. If yes, then proceed with the backups, if no then raise the flag.

This is the snipet of the code. i have removed the exception block and some logging I do.

procedure START_ARCHIVE
is
n_START NUMBER := dbms_utility.get_time;
n_CURRYEAR NUMBER := substr(SYSDATE,8,9);
n_CNT NUMBER;
e_RAISE_NO_TABLE EXCEPTION;
n_TABYEAR CHAR(2);
v_SELSTMT VARCHAR(1000);
n_EXPCNT NUMBER:=0;

BEGIN
for j in (select distinct(substr(TIMSTAMP,8,9)) n_YEAR from SEOSDATA where trunc(TIMSTAMP,'YYYY') < trunc(SYSDATE,'YYYY'))
loop
BEGIN
select count(*) into n_CNT from DUAL where exists
(select TABLE_NAME from USER_TABLES where TABLE_NAME='SEOSDATA'||j.n_YEAR);

if (n_CNT = 0) then
n_TABYEAR := j.n_YEAR;
raise e_RAISE_NO_TABLE;
end if;

n_EXPCNT := 1;

execute immediate 'insert into SEOSDATA'||j.n_YEAR||' select * from SEOSDATA where to_char(substr(TIMSTAMP,8,9))='||j.n_YEAR||'
and substr(TIMSTAMP,8,9) < substr(SYSDATE,8,9)';

delete from SEOSDATA where substr(TIMSTAMP,8,9)=j.n_YEAR;


end loop;

if n_EXPCNT=0 then
raise NO_DATA_FOUND;
end if;

commit;

end;

Tom Kyte
September 24, 2006 - 1:13 pm UTC

you use the word "backup" and I see procedural code, so now I am really "concerned" because this is not a backup of anything, it might be a "logical copy", but backup - this ain't.

I still don't follow your logic (posting code that doesn't work, doesn't help - I'm assuming the code doesn't work, else you would not be asking. posting logic that does not accomplish your goal only confuses the issue...)

IF you want it so that if the three tables do not exist, then just write that logic, logic that says "let us raise an exception if our tables do not exist"

Heck, you could just let the code run, if the table(s) do not exist, the code will fail - you didn't need to check necessarily.

A reader, September 25, 2006 - 10:03 am UTC

Here is the entire code. This code works and creates the copy of the table one by one for each value of loop j. If it does not find the table (say SEOSDATA05) after the 1st iteration of the loop for the previous year (SEOSDATA04), it rollsback. So where do i put in this exception logic.

--- create or replace package body SEOSDATA_BKP
as
procedure LOG_DATA(v_OPERATION in VARCHAR2,v_MSG in VARCHAR2, v_STATUS in VARCHAR2)
is

v_TERMINAL VARCHAR2(200);
v_OSUSER VARCHAR2(15);
n_SEQ NUMBER;
pragma autonomous_transaction;

begin
select
sys_context('userenv','os_user'),
sys_context('userenv','host'),
audit_log_seq.nextval
into
v_OSUSER,
v_TERMINAL,
n_SEQ
from
DUAL;

insert into AUDIT_LOG
(OPERATION, SOURCE_SCHEMA, AUDIT_ACTION, TIME_STAMP, TERMINAL, OS_USER, SEQ_NO, STATUS
)
values
(v_OPERATION, USER, v_MSG, SYSDATE, v_TERMINAL, v_OSUSER, n_SEQ,v_STATUS);

commit;
end;


procedure START_ARCHIVE
is
n_START NUMBER := dbms_utility.get_time;
n_CURRYEAR NUMBER := substr(SYSDATE,8,9);
n_CNT NUMBER;
e_RAISE_NO_TABLE EXCEPTION;
n_TABYEAR CHAR(2);
n_SRC1CNT NUMBER;
n_SRC2CNT NUMBER;
v_SELSTMT VARCHAR(1000);
n_EXPCNT NUMBER:=0;

BEGIN
-- For j in ( ) is faster than Open cursor, Fetch cursor.
for j in (select distinct(substr(TIMSTAMP,8,9)) n_YEAR from SEOSDATA where trunc(TIMSTAMP,'YYYY') < trunc(SYSDATE,'YYYY'))
loop
BEGIN

select count(*)
into n_CNT
from DUAL
where exists
(select TABLE_NAME
from USER_TABLES
where TABLE_NAME='SEOSDATA'||j.n_YEAR);

if (n_CNT = 0) then
n_TABYEAR := j.n_YEAR;
raise e_RAISE_NO_TABLE;
end if;

n_EXPCNT := 1;
-- Insertion of Data according to Year in Backup Table.
execute immediate 'insert into SEOSDATA'||j.n_YEAR||
' select * from SEOSDATA
where to_char(substr(TIMSTAMP,8,9))='||j.n_YEAR||'
and substr(TIMSTAMP,8,9) < substr(SYSDATE,8,9)';


-- Comparing Counts of 2 Identical Tables before Deletion.
v_SELSTMT := 'select count(SRC1), count(SRC2) from
(select SEOSDATA.*, 1 SRC1, to_number(null) SRC2
from SEOSDATA
where substr(TIMSTAMP,8,9)='||j.n_YEAR||'
union all
select SEOSDATA'||j.n_YEAR||'.*, to_number(null) SRC1, 2 SRC2
from SEOSDATA'||j.n_YEAR||')';
execute immediate v_SELSTMT into n_SRC1CNT, n_SRC2CNT;


if n_SRC1CNT = n_SRC2CNT then
log_data('SEOSDATA Archive','Table SEOSDATA'||j.n_YEAR||' archived with '||n_SRC2CNT||' rows for Year 20'||j.n_YEAR,'S');
delete from SEOSDATA where substr(TIMSTAMP,8,9)=j.n_YEAR;

else
log_data('SEOSDATA Archive','Row Count '||n_SRC1CNT||' of SEOSDATA <> Row count '||n_SRC2CNT||' of SEOSDATA'||j.n_YEAR||'-- Rollback','F');
rollback;
end if;
END;
end loop;

if n_EXPCNT=0 then
raise NO_DATA_FOUND;
end if;

commit;
log_data('SEOSDATA Archive','The SEOSDATA Archive Complete in '||round((dbms_utility.get_time-n_START)/100,2)||' secs','C');

EXCEPTION
when e_RAISE_NO_TABLE then
log_data('SEOSDATA Create Table',
'Table SEOSDATA'||n_TABYEAR||' does not exist!!. Program Exit in '||round((dbms_utility.get_time-n_START)/100,2)||' secs',
'F');
raise_application_error(-20001,'The table SEOSDATA'||n_TABYEAR||' does not exist!!! Create Manually and grant appr rights');
rollback;

when NO_DATA_FOUND then
log_data('SEOSDATA Archive',
'No rows in Table SEOSDATA for previous years. Program Exit in '||round((dbms_utility.get_time-n_START)/100,2)||' secs',
'F');

when OTHERS then
log_data('SEOSDATA Archive',' Error-- '||SQLERRM,'F');

END;
end SEOSDATA_BKP;
---

Tom Kyte
September 25, 2006 - 3:07 pm UTC

please re-read my second paragraph above. if you don't know where to put an exception block in some bit of code - why would I (given that it is your code)

I don't really know what you are doing and I'm not going to read a bunch of code and try to figure it out.

Confused

Shankar Ram, September 28, 2006 - 5:14 pm UTC

Hi,
I'm learning this new concept of pipelined functions. I have a scenario.

STEP 1 - select query is generated and a list of addresses are resulted.
STEP 2 pipelined function is created and stores the value of this result.
STEP 3 Stored addresses are checked and status columns is updated for each address.
STEP 4 Some other function uses this status record for its DML
STEP 5 Now I want to reset this pipelined function so that it can be used again. How do I reset the pipelined functions.

Is this scenario requires pipelined functions? Do you have any other suggestion on this.


Thanks
Shankar Ram


Tom Kyte
September 29, 2006 - 7:58 am UTC

I don't know what you mean by "how do I reset the pipelined function"

step 2 doesn't make sense, you would not create code on the fly.


you would "reset" any package global state (which you must be using???) in the same fashion.

you write a procedure in your package that sets the package global variables to "safe" initial values again.

How does rownum >=0 make oracle execute the query faster?

A reader, November 03, 2006 - 6:48 am UTC

<quote>
it doens't know the cardinality of the str2tbl and is guessing 8,168 rows.

i would do two things:

a) add "where rownum >= 0" to the subqueries
b) add /*+ FIRST_ROWS */ to the outer query
</quote>

I understand point b (I think), but not quite sure how rownum >= 0 makes oracle execute the query faster. This actually worked for me and so I am really curious. Please bear with me as I am a bit of a newbie.

Thanks in advance

Tom Kyte
November 03, 2006 - 10:42 am UTC

it is like using the no_merge hint, it'll run the procedure ONCE and put results into temp, instead of potentially running the procedure ONCE PER ROW in the outer query

in_list

Raj, December 04, 2006 - 11:25 pm UTC

Hi Tom,

I tried the following case where it gives for me always 0 rows inserted in emp_temp.

I don't know what is going on wrong..

EMP TABLE:

eno number
deptno number
id_pack_mode char(1)

values are

101 10 4
102 20 3
103 30 2
104 40 1
105 10 1
106 10 2

EMP_TEMP TABLE:

eno number
deptno number
id_pack_mode char(1)


The employee table has got 6 rows and it contains the id_pack_mode as (1,2,3,4) which is character value. The following is the way where I am trying to populate the data in EMP_TEMP Table.

create or replace procedure test_mode
is
lv_pack_mode varchar2(100);
fl_case_pack char(1);

begin

select fl_casepack_only
into fl_case_pack
from t01_ctrl;

if NVL(FL_CASE_PACK,'N') = 'Y' THEN
-- lv_pack_mode := 4;
lv_pack_mode := (1||','||2||','||3||','||4);
end if;

sys.dbms_output.put_line('The lv pack mode is'||lv_pack_mode);

insert into emp_temp
( empno,
deptno
id_pack_mode
)
select empno, deptno, id_pack_mode
from emp
where id_pack_mode in ( lv_pack_mode);

sys.dbms_output.put_line('The ROWS INSERTED'||SQL%ROWCOUNT);

commit;

exception
when others then
sys.dbms_output.put_line('It is in Exception'||SQLERRM);
end;


I suppose to get the 6 rows in EMP_TEMP Table as well. But it is not happening. Is something which I am missing.


In the dbms output it is showing the values as 1,2,3,4 against the lv_pack_mode.. For one value it is working properly. When I am doing concatenation it is inserting zero rows.

Environment is Oracle 9i 9.2.0.4 on Unix.


Tom Kyte
December 05, 2006 - 9:53 pm UTC

umm, please - read the original answer above. It applies 100% to you - entirely.




in_list

RAJ, December 05, 2006 - 11:48 pm UTC

Hi Tom,

Thanks for your recommendation. I used the in_list function and it worked for me what I am expecting.

It is working fine by giving the value as
where id_pack_mode in (1,2,3,4)

It is not working by giving the following way
where id_pack_mode in (lv_id_pack_mode)
lv_id_pack_mode := 1||','||2||','||3||','||4

One thing which i would like to understand here is
eventhough id_pack_mode is CHAR(1), The values I am passing in lv_id_pack_mode is number concetenation with commas. why it is not working and what is the cause for this..

Reply would be appreciated.





Tom Kyte
December 06, 2006 - 9:41 am UTC

i don't know what else to say.

read the original answer - it applies 100% to you.


if you go:

where id_pack_mode in ( lv_id_pack_mode )

you by DEFINITION have an inlist with a SINGLE ITEM IN IT.  I matters not you have set lv_id_pack_mode to a comma delimited list, it is just a SINGLE STRING


ops$tkyte%ORA10GR2> create table t ( x varchar2(20) );

Table created.

ops$tkyte%ORA10GR2> insert into t values ( 1 );

1 row created.

ops$tkyte%ORA10GR2> insert into t values ( 2 );

1 row created.

ops$tkyte%ORA10GR2> insert into t values ( 3 );

1 row created.

ops$tkyte%ORA10GR2> insert into t values ( 4 );

1 row created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> declare
  2          lv_id_pack_mode varchar2(20);
  3  begin
  4          lv_id_pack_mode := 1||','||2||','||3||','||4;
  5          insert into t values ( lv_id_pack_mode );
  6
  7          for x in ( select * from t where x in (lv_id_pack_mode) )
  8          loop
  9                  dbms_output.put_line( 'result: ' || x.x );
 10          end loop;
 11  end;
 12  /
result: 1,2,3,4

PL/SQL procedure successfully completed.


See, it can only find the row where x = the ENTIRE STRING, they are not, could not, should not be considered four separate elements - you only passed in ONE SINGLE STRING. 

Using collection in SQL

Sunj, January 30, 2007 - 2:14 pm UTC

Tom,
My question is related, but I couldn't find my specific answer after searching through this and related threads.

I am using a function similar to your in_list() to retun a collection table in SQL.

my_tab table has 1/2 million rows.
CREATE TABLE my_tab (
question_id NUMBER,
answer_list VARCHAR2(500),
client_id NUMBER
);

INSERT INTO my_tab values (1, '10,20,30,40,50',101);
INSERT INTO my_tab values (2, '10,20,60,80,70',103);
INSERT INTO my_tab values (3, '100,130,40,50,80,90,10',101);
INSERT INTO my_tab values (4, '10,20,30,40,50',103);

This query returns in less than a second.
SELECT d.client_id, a.answer_id, count(*) cnt
FROM my_tab d,
TABLE
(
list_to_object_table(d.answer_list)
) a
where rownum < 500001
GROUP BY d.client_id, a.answer_id
ORDER BY d.client_id ASC,
cnt DESC;

When I remove the ROWNUM clause, it takes 1.5 minutes.
Why is the difference in performance, eventhough the result is same?

Thanks
Sunj
Tom Kyte
January 31, 2007 - 10:10 am UTC

compare plans - I would guess that with rownum - the TABLE() clause is being materialized into temp and then processed, without it - the TABLE() clause might be evaluated over and over.

Using collection in SQL

Sunj, February 01, 2007 - 12:52 pm UTC

Tom,
Thanks for your insight.

Using collection in SQL
Doesn't the TABLE() have to be evaluated for each row anyway?

I compared the PLANs, there's big difference in cardinality. Wonder why?

Plan when I have ROWNUM < 50000
SELECT STATEMENT  ALL_ROWSCost: 25 M  Bytes: 150 M  Cardinality: 590 K  
  6 SORT ORDER BY  Cost: 25 M  Bytes: 150 M  Cardinality: 590 K          
    5 HASH GROUP BY  Cost: 25 M  Bytes: 150 M  Cardinality: 590 K        
      4 COUNT STOPKEY      
        3 NESTED LOOPS  Cost: 22 M  Bytes: 2657 G  Cardinality: 11 G    
          1 TABLE ACCESS FULL TABLE MHXMLADMIN.SUNIL_SURVEY Cost: 869  Bytes: 165 M  Cardinality: 653 K  
          2 COLLECTION ITERATOR PICKLER FETCH PROCEDURE PK_COMMON_SUN.LIST_TO_OBJECT_TABLE 


Plan when I don't have rownum filter
SELECT STATEMENT  ALL_ROWSCost: 25 M  Bytes: 2657 G  Cardinality: 11 G          
  5 SORT ORDER BY  Cost: 25 M  Bytes: 2657 G  Cardinality: 11 G        
    4 HASH GROUP BY  Cost: 25 M  Bytes: 2657 G  Cardinality: 11 G      
      3 NESTED LOOPS  Cost: 22 M  Bytes: 2657 G  Cardinality: 11 G    
        1 TABLE ACCESS FULL TABLE MHXMLADMIN.SUNIL_SURVEY Cost: 869  Bytes: 165 M  Cardinality: 653 K  
        2 COLLECTION ITERATOR PICKLER FETCH PROCEDURE PK_COMMON_SUN.LIST_TO_OBJECT_TABLE 

Tom Kyte
February 01, 2007 - 1:24 pm UTC

the count stopkey materialized a sub-result that was then used in the hash group and sort steps.

as opposed to the one without - whereby the table() function was undoubtedly invoked many more times - since the subresult was not materialized.

Another

Venkat, February 02, 2007 - 8:04 am UTC

Sunj,
There is also one more way in Oracle you can achieve this..I dont know how would it suit your requirement but if you have 10G...the following thing works

SELECT * FROM TABLE(SPLIT('1,2,3,4,5,6'))

Using collection in SQL

Sunj, February 06, 2007 - 2:50 pm UTC

Tom,
Thank you for interpreting the plan for me in detail. Much appreciate your time.

Venkat,
I couldn't find SPLIT() function in 10g. Thanks you too.

Can I use hierarchichal query for this?

A reader, May 08, 2007 - 12:59 pm UTC

Connected to Oracle9i Enterprise Edition Release 9.2.0.5.0
Connected as test

SQL>
create table test_data(id VARCHAR2(9),S1 VARCHAR2(10), S2 VARCHAR2(10));

Table created
insert into test_data(id,s1,s2) values('1','1234','ABCD');

1 row inserted
insert into test_data(id,s1,s2) values('A','abc','123');

1 row inserted
commit;

Commit complete
select * from test_data;

ID S1 S2
--------- ---------- ----------
1 1234 ABCD
A abc 123

SQL>

Dear Tom! Number of characters in S1 and S2 are always the same for particular record. I'm trying to build query that returns this:
1,1,A
1,2,B
1,3,C
1,4,D
A,a,1
A,b,2
A,c,3
In other words, every record from the original table should be transformed to variable number of records (including 0 if S1 and S2 are null).
I was able to implement it easily with pipe function that parses every input record and returns result records. But I'd like to have it done by this elegant hierarchichal query solution (using level etc). The reason is trying to stay in SQL - while processing couple of millions of records like this (and real structure is more complicated) performance is not acceptable: I believe due to PLSQL/SQL context switch. I tried, but failed. You help/advice would be highly appreciated! Thanks a lot!
Tom Kyte
May 11, 2007 - 8:17 am UTC

ops$tkyte%ORA9IR2> with data
  2  as
  3  (select level n from dual connect by level <= 10)
  4  select id, n, substr( s1, n, 1 ) s1, substr( s2, n, 1 ) s2
  5    from test_data, data
  6   where data.n <= length(test_data.s1)
  7   order by id, n
  8  /

ID                 N S S
--------- ---------- - -
1                  1 1 A
1                  2 2 B
1                  3 3 C
1                  4 4 D
A                  1 a 1
A                  2 b 2
A                  3 c 3

7 rows selected.

Thank you but...

A reader, May 11, 2007 - 12:09 pm UTC

Thanks a lot! But unfortunately this level can be as deep as 100 which actually increased processing time in comparison with pipe function :-(
Tom Kyte
May 11, 2007 - 1:34 pm UTC

well, define "not acceptable" beyond "not acceptable"

you have a couple of million records
you are "processing them"
you say the time is "not acceptable"

time to put some "boundaries" on these terms so as to see if you are being reasonable :)

Heartfelt thanks and a pointer for others

Stew Ashton, June 26, 2007 - 6:16 am UTC


Tom, I have used your "varying in list" solutions to great effect, but I had big problems with a complex query: the optimizer went for hash joins and ignored most all my indexes, and response times were disappointing.

After almost giving up, I finally happened upon followups about the cardinality hint and the rownum >= 0 trick. Used together, they get me excellent plans and response times.

I felt I had to thank you for once again turning a frustrating problem into a finger-snapping solution. I'm adding a pointer to one of your followups in case it helps others find it faster than I did :)

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:3779680732446#15740265481549

ORA-03113 Error while using dynamic IN List

Gopalakrishnan, July 13, 2007 - 10:23 am UTC

Hi Tom,

Please find the following query.
select col1 from table_name where col1 in (select col_value from table(cast(fnc_string_to_row('a,b,c,d') as string_to_row)))


I am using the above query inside a function and returning the values to a nested table. while calling that function, I am getting an error "ORA-03113: end-of-file on communication channel". If I replace the inside query with single value('a') then it works. Please help me to solve this problem.

Thanks & Regards,
Gopal.
Tom Kyte
July 13, 2007 - 10:43 am UTC

ora-3113, 7445, 600 => utilize support

In List variabe

Dee, August 07, 2007 - 2:43 pm UTC


Thank you for having this great site!

My question involves passing a string of numbers to a select statement.

I have a stored procedure that concatenates a list of numbers using a comma to separate the values. The list is stored in a string variable called v_request_final

In debug mode the values of v_request final is exactly '31026, 31308'

I now want to pass the variable to a select statement by doing something like this with request_id being a NUMBER.

v_request_query := ' and request_id IN (:v_request_final);
l_query := l_query || v_request_query;

OPEN l_cursor for l_query using p_parameter, v_request_final;
LOOP
FETCH l_cursor into l_rec;
EXIT WHEN l_cursor%NOTFOUND;
dbms_output.put_line( l_rec.request_id );
END LOOP;
END;
------------------------------------------------------------
Unfortunately it isn't quite working; I am getting errors with bind variables. I tried using ltrim and rtrim to remove the quotes from the string but so far I am unsuccessful.

Any suggestions is greatly appreciated as I am somewhat of a novice. I will continue to read this thread for further code suggestions that I can use. The definitions for l_query are listed below for reference.

Thank you,

Dee


-The definitions of l_query were made earlier in the code-

l_query VARCHAR2(3000)
DEFAULT ('SELECT *
FROM view_open_req
WHERE 1=1');

TYPE RC IS REF CURSOR;
l_cursor RC;

CURSOR l_template IS
SELECT *
FROM view_open_req
WHERE 1=1 ;

l_rec l_template%ROWTYPE;
-----------------------------------------------------------

in lists

Sam, August 13, 2007 - 11:30 pm UTC


How can I do a variable "in list

Dee, August 16, 2007 - 11:05 am UTC

Hello Tom,

Thank you for the great detailed solution on your Blog site:
Varying in Lists - I always learn something new by implementing your suggested code!


I successfully applied the 8i solution to my Oracle package; (I can use SQL to view the 9iR2 solution but received errors regarding not all variables being bound when I incorporated it into my package )

Question regarding performance on both these solutions... In comparison to just an IN sql statement, they seem to run a little slower. Is there anything further that can be done about performance?

select * from view_open_req where request_id in (34159, 29512, 8856, 37602, 34139, 37602)

executes in .34 seconds
-----------------------------------------------------

select *
from view_open_req
where request_id in
(select *
from TABLE( cast( str2tbl('34159, 29512, 8856, 37602, 34139, 37602') as str2TblType ) ))

executes in 28.14 seconds
---------------------------------------------------
with data
as
(select
trim( substr ('34159, 29512, 8856, 37602, 34139, 37602',
instr ('34159, 29512, 8856, 37602, 34139, 37602', ',', 1, level ) + 1,
instr ('34159, 29512, 8856, 37602, 34139, 37602', ',', 1, level+1)
- instr ('34159, 29512, 8856, 37602, 34139, 37602', ',', 1, level) -1 ) )
as token
from (select ','||'34159, 29512, 8856, 37602, 34139, 37602'||',' txt
from dual)
connect by level <= length('34159, 29512, 8856, 37602, 34139, 37602')-length(replace('34159, 29512, 8856, 37602, 34139, 37602',',',''))+1
)
select *
from view_open_req
where request_id in (select * from data);

executes 18.4 seconds

---------------------------------

Thanks again for all your efforts and collaboration!

Dee


Tom Kyte
August 20, 2007 - 10:06 pm UTC

look at the plans please - are they different. we need to start there.

A reader, August 22, 2007 - 9:18 am UTC

If we have large values in then IN_List view dont return all the values. Is there some max length?
Tom Kyte
August 22, 2007 - 2:03 pm UTC

in sql (not plsql, sql) varchar2 binds are limited to 4000 characters - is that the issue for you?

A reader, August 23, 2007 - 12:58 am UTC

I am passing this string which contains 41 values but view returns me 27 values
793178994,74430189,979777790,934009393,478787739,70731413,107998083,970798439,708179438,807007739,918337439,379348870,300713393,949873993,918091939,377399834,173009933,943774973,939737779,709904389,913339870,70778049,389308349,370744884,74419399,747783183,977799334,848703839,337909303,934089397,194898070,979473977,773989343,149719808,197301103,707397771,4413373,198979370,307987394,377939904,937989733
Tom Kyte
August 23, 2007 - 11:26 am UTC

prove it:


ops$tkyte%ORA10GR2> create or replace type myTableType as table
  2  of varchar2 (255);
  3  /

Type created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create or replace
  2  function in_list( p_string in varchar2 ) return myTableType
  3  as
  4      l_string        long default p_string || ',';
  5      l_data          myTableType := myTableType();
  6      n               number;
  7  begin
  8    loop
  9        exit when l_string is null;
 10        n := instr( l_string, ',' );
 11        l_data.extend;
 12        l_data(l_data.count) :=
 13              ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
 14        l_string := substr( l_string, n+1 );
 15   end loop;
 16   return l_data;
 17  end;
 18  /

Function created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select * from table( in_list(
  2  '793178994,74430189,979777790,934009393,478787739,70731413,107998083,970798439,708179438,807007739,918337439,379348870,300713393,949873993,918091939,377399834,173009933,943774973,939737779,709904389,913339870,70778049,389308349,370744884,74419399,747783183,977799334,848703839,337909303,934089397,194898070,979473977,773989343,149719808,197301103,707397771,4413373,198979370,307987394,377939904,937989733') )
  3  /

COLUMN_VALUE
-------------------------------------------------------------------------------
793178994
74430189
979777790
...
377939904
937989733

41 rows selected.


A reader, August 24, 2007 - 1:57 am UTC

scott> create or replace context my_ctx using my_ctx_procedure;

Context created.

scott> create or replace
  2    procedure my_ctx_procedure
  3    ( p_str in varchar2 )
  4    as
  5    begin
  6            dbms_session.set_context
  7            ( 'my_ctx', 'txt', p_str );
  8    end;
  9    /


Procedure created.

scott>  create or replace view IN_LIST
  2        as
  3        select
  4          trim( substr (txt,
  5                instr (txt, ',', 1, level  ) + 1,
  6                instr (txt, ',', 1, level+1)
  7                   - instr (txt, ',', 1, level) -1 ) )
  8            as token
  9          from (select ','||sys_context('my_ctx','txt')||',' txt
 10                from dual)
 11       connect by level <=
 12          length(sys_context('my_ctx','txt'))
 13            -length(replace(sys_context('my_ctx','txt'),',',''))+1;

View created.

scott> exec my_ctx_procedure('793178994,74430189,979777790,934009393,478787739,70731413,107998083,970798439,708179438,807007739,918337439,379348870,300713393,949873993,918091939,377399834,173009933,943774973,939737779,709904389,913339870,70778049,389308349,370744884,74419399,747783183,977799334,848703839,337909303,934089397,194898070,979473977,773989343,149719808,197301103,707397771,4413373,198979370,307987394,377939904,937989733');

PL/SQL procedure successfully completed.

scott> select *
  2  from in_list
  3  ;

TOKEN                                                                           
--------------------------------------------------------------------------------
793178994                                                                       
74430189                                                                        
979777790                                                                       
934009393                                                                       
478787739                                                                       
70731413                                                                        
107998083                                                                       
970798439                                                                       
708179438                                                                       
807007739                                                                       
918337439                                                                       

TOKEN                                                                           
--------------------------------------------------------------------------------
379348870                                                                       
300713393                                                                       
949873993                                                                       
918091939                                                                       
377399834                                                                       
173009933                                                                       
943774973                                                                       
939737779                                                                       
709904389                                                                       
913339870                                                                       
70778049                                                                        

TOKEN                                                                           
--------------------------------------------------------------------------------
389308349                                                                       
370744884                                                                       
74419399                                                                        
747783183                                                                       
                                                                                

27 rows selected.

scott> spool off

Tom Kyte
August 24, 2007 - 2:57 pm UTC

that is precisely why concise YET 100% complete (but short) test cases are mandatory :)


ops$tkyte%ORA10GR2> exec my_ctx_procedure('793178994,74430189,979777790,934009393,478787739,70731413,107998083,970798439,708179438,807007739,918337439,379348870,300713393,949873993,918091939,377399834,173009933,943774973,939737779,709904389,913339870,70778049,389308349,370744884,74419399,747783183,977799334,848703839,337909303,934089397,194898070,979473977,773989343,149719808,197301103,707397771,4413373,198979370,307987394,377939904,937989733');

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select sys_context( 'my_ctx', 'txt' ) from dual;

SYS_CONTEXT('MY_CTX','TXT')
-------------------------------------------------------------------------------
793178994,74430189,979777790,934009393,478787739,70731413,107998083,970798439,7
08179438,807007739,918337439,379348870,300713393,949873993,918091939,377399834,
173009933,943774973,939737779,709904389,913339870,70778049,389308349,370744884,
74419399,747783183,


ops$tkyte%ORA10GR2> select sys_context( 'my_ctx', 'txt', 4000 ) from dual;

SYS_CONTEXT('MY_CTX','TXT',4000)
-------------------------------------------------------------------------------
793178994,74430189,979777790,934009393,478787739,70731413,107998083,970798439,7
08179438,807007739,918337439,379348870,300713393,949873993,918091939,377399834,
173009933,943774973,939737779,709904389,913339870,70778049,389308349,370744884,
74419399,747783183,977799334,848703839,337909303,934089397,194898070,979473977,
773989343,149719808,197301103,707397771,4413373,198979370,307987394,377939904,9
37989733




The problem isn't with our code, but rather the fact you introduced sys_context in there and sys_context by default (for backwards compatibility) returns 255 characters only - unless you tell it "more"

Error in Cursor

Raymond, September 06, 2007 - 11:24 pm UTC

Hi Tom,

I'm getting error in my cursor

Cursor C1 (pParentProdRelId SH_PACKAGE_MEMBER.shParentProdRelId%Type,
pTechProdRelId SW_PROD_RELEASE.shTechReleaseId%Type,
pCustomerSegment SH_AVAILABLE_PRODUCT.shSegment%Type,
pChildProdRelId SH_PACKAGE_MEMBER.shChildProdRelId%TYPE,
pLinkPackage VARCHAR2,
pCount INT) IS
Select Distinct r.swProdReleaseId, r.swName, p.shPackageMemberId
from SW_PROD_RELEASE r, SH_PACKAGE_MEMBER p, SH_COM_PROD c, SW_PROD_RELEASE pr,SH_AVAILABLE_PRODUCT a, SH_COM_PROD c2
Where p.shParentProdRelId = pParentProdRelId
and pr.swProdReleaseId = pParentProdRelId
and p.shChildProdRelId = r.swProdReleaseId
and p.shChildProdRelId <> pChildProdRelId
and r.shTechReleaseId = pTechProdRelId
and r.swProdReleaseId = c.swProdReleaseId
and c.swProductLineId = c2.swProductLineId
and a.shSegment = pCustomerSegment
and c2.swProductLineId = a.swProductlineId
and c2.swProdReleaseId = pChildProdRelId
and r.swExternalRelease > 0
and p.shConfigStatus = 1
AND ((pCount = 1 AND p.shLinkPackage = 1)OR
(pCount = 0 AND nvl(p.shLinkPackage,0) IN (SELECT to_number(COLUMN_VALUE) FROM TABLE(CAST(in_list(pLinkPackage) AS myTableType)))));

Error: PLS-00801: internal error [22914]
Line: 10
Text: Select Distinct r.swProdReleaseId, r.swName, p.shPackageMemberId

Error: PL/SQL: SQL Statement ignored
Line: 10
Text: Select Distinct r.swProdReleaseId, r.swName, p.shPackageMemberId

Error: PLS-00320: the declaration of the type of this expression is incomplete or malformed
Line: 10
Text: Select Distinct r.swProdReleaseId, r.swName, p.shPackageMemberId

Error: PL/SQL: SQL Statement ignored
Line: 320
Text: FETCH C1 into pTargetPackageId(iCntr)

Btw, My Oracle version is 8.1.7

Thks,
Raymond
Tom Kyte
September 11, 2007 - 8:37 am UTC

make it smaller
make it complete

do the smallest test case possible - including all creates and everything

so we can cut and paste and run it ourself.


Also, internal error would indicate "time to contact support please"

Solved

A reader, September 10, 2007 - 11:03 pm UTC

Hi Tom,

You can ignore my question as I already found the answer, it seems there is a bug in PL/SQL engine on 8i when putting TABLE function, therefor I'm changing it to THE function.
And it works fine.

Rgds,

instr with array elements

sara, October 26, 2007 - 2:37 pm UTC

Hi Tom,

I need to run an instr function against an array. ie. for example in the array I have like
'ADD','MUL','SUB','DIV'......

select ...
where instr(col1 , 'ADD') > 0 OR
instr(col1 , 'MUL') > 0 Or
instr(col1 , 'SUB') > 0 OR
instr(col1 , 'DIV') > 0
Instead of the above
I want to check against the array.
How do I do that?

I created :
CREATE OR REPLACE TYPE string_array IS TABLE OF VARCHAR2(200);

DECLARE
list string_array := string_array();
list(1) := 'ADD';
list(2) := 'MUL';
list(3) := 'SUB';
list(4) := 'DIV';
...
select ..
from ..
where
(instr(col1, (SELECT * FROM TABLE(CAST(list AS string_array)) ) )> 0 );

gives me error.

I need to use the array as I have to check the same values against another col too.
could you please guide me how to proceed?

Thanks in advance

Sara
Tom Kyte
October 29, 2007 - 11:41 am UTC

... I need to use the array as I have to check the same values against another col
too. ...

I do not see the cause and effect here - why would the fact you are checking another column MANDATE an array?

Using materialize in the following to make it so that plsql function gets called ONCE.

Using cardinality just to push in a representative number of rows expected back - for the optimizer in general.


ops$tkyte%ORA10GR2> create table t as select * from all_users;

Table created.

ops$tkyte%ORA10GR2> variable list varchar2(20)
ops$tkyte%ORA10GR2> exec :list := 'SYS,SCOTT,'||user

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> with data
  2  as
  3  (select /*+ materialize cardinality(x,10) */ * from TABLE(str2tbl(:list)) x )
  4  select t.*,
  5         (select 1
  6            from data
  7           where instr(t.username,data.column_value)>0
  8             and rownum = 1) flag
  9    from t
 10  /

USERNAME                          USER_ID CREATED         FLAG
------------------------------ ---------- --------- ----------
BIG_TABLE                              58 14-DEC-05
DIP                                    19 30-JUN-05
TSMSYS                                 21 30-JUN-05          1
LOTTOUSER                              65 30-DEC-05
MDDATA                                 50 30-JUN-05
OPS$ORA10GR2                           56 14-DEC-05
FOO$TKYTE                              60 19-DEC-05
QUOTA                                  94 22-FEB-06
AQ                                    228 15-OCT-07
R                                      76 09-JAN-06
OPS$TKYTE                             229 29-OCT-07          1
SCOTT                                  84 12-FEB-06          1
B                                     213 08-JAN-07
A                                     221 04-SEP-07
DMSYS                                  35 30-JUN-05          1
DBSNMP                                 24 30-JUN-05
WMSYS                                  25 30-JUN-05          1
EXFSYS                                 34 30-JUN-05          1
CTXSYS                                 36 30-JUN-05          1
XDB                                    38 30-JUN-05
ANONYMOUS                              39 30-JUN-05
OLAPSYS                                47 30-JUN-05          1
ORDSYS                                 43 30-JUN-05          1
ORDPLUGINS                             44 30-JUN-05
SI_INFORMTN_SCHEMA                     45 30-JUN-05
MDSYS                                  46 30-JUN-05          1
SYSMAN                                 51 30-JUN-05          1
PERFSTAT                              148 31-MAR-06
SYS                                     0 30-JUN-05          1
SYSTEM                                  5 30-JUN-05          1
OUTLN                                  11 30-JUN-05
MGMT_VIEW                              53 30-JUN-05
MY_USER                               211 09-NOV-06

33 rows selected.

ops$tkyte%ORA10GR2> with data
  2  as
  3  (select /*+ materialize cardinality(x,10) */ * from TABLE(str2tbl(:list)) x )
  4  select *
  5    from t
  6   where (select 1
  7            from data
  8           where instr(t.username,data.column_value)>0
  9             and rownum = 1) = 1
 10  /

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
TSMSYS                                 21 30-JUN-05
OPS$TKYTE                             229 29-OCT-07
SCOTT                                  84 12-FEB-06
DMSYS                                  35 30-JUN-05
WMSYS                                  25 30-JUN-05
EXFSYS                                 34 30-JUN-05
CTXSYS                                 36 30-JUN-05
OLAPSYS                                47 30-JUN-05
ORDSYS                                 43 30-JUN-05
MDSYS                                  46 30-JUN-05
SYSMAN                                 51 30-JUN-05
SYS                                     0 30-JUN-05
SYSTEM                                  5 30-JUN-05

13 rows selected.


Ashish, October 30, 2007 - 11:12 am UTC

Hi Tom,
Do you know the limit of in clause in Oracle 10G or in other words how many items we can have in the in list

Thanx
Tom Kyte
October 30, 2007 - 1:23 pm UTC

practically speaking, if you go over hundreds, you don't want to use an IN list anymore.

You would either be using this technique or as likely, a global temporary table that you array insert your values into and then use in a subquery.

http://asktom.oracle.com/Misc/varying-in-lists.html

(eg: I'm not going to look up the real limit, that you could look up in the reference guide, but rather I'm going to say that since you MUST use bind variables - and you don't have the patience to bind hundreds of values, you will either use the technique pointed to OR you will place these values into a global temporary table)

can we pass muiltple values to a parameter using sys_context ?

K Kiran, November 05, 2007 - 3:29 pm UTC

Hi Tom,

This is my proc.

create or replace PROCEDURE "SR"
(
p_RType IN VARCHAR2,
p_J_Status IN VARCHAR2,
p_R_Status IN CHAR,
p_M_Status IN CHAR DEFAULT ' ',
p_SO IN VARCHAR2,
p_Days IN NUMBER DEFAULT 31,
p_RetVal IN OUT TYPES.cursor_type,
p_Delimiter IN CHAR,
p_SQL IN OUT VARCHAR2
)
AS
v_J_Status VARCHAR2(500);
v_SqlSelect VARCHAR2(3000);
v_SqlFrom VARCHAR2(30000);
v_SqlWhere VARCHAR2(30000);
v_SqlComplete VARCHAR2(30000);
v_SqlCountComplete VARCHAR2(30000);
v_newDate DATE;

BEGIN
IF p_RType = 'Something' THEN

v_SqlSelect := v_SqlSelect || 'SELECT J.Id AS JId ' ;

v_SqlFrom := ' FROM J ';

v_SqlWhere := ' WHERE 1=1';

IF LENGTH(p_J_Status) != 0 THEN
IF p_J_Status != 'All' THEN
v_J_Status := REPLACE(p_J_Status, p_Delimiter, ''',''') ;
dbms_session.set_context( 'S_R_CTX', 'v_J_Status',v_J_Status);
v_SqlWhere := v_SqlWhere || ' AND Job.Status_Lu IN (sys_context( ''S_R_CTX'', ''v_J_Status'' )) ';
END IF;
END IF;

v_SqlComplete := v_SqlSelect || v_SqlFrom || v_SqlWhere;

OPEN p_retVal FOR v_SqlComplete;
p_SQL := v_SqlComplete;

the parameter shud take values for v_J_Status as '1','2','3','4' ..... how can i assign this ??

I cannot pass the values to the variable as '1','2','3','4' .. but can pass it as '1,2,3,4';

Please give me a solution

One Clarification

Muhammad Riaz Shahid, January 02, 2008 - 3:12 pm UTC

Hi Tom,
If the max no. of values in IN list are known (15 for me), would you suggest using str2tbl or directly refer them in the IN clause like:

WHERE <Col> IN (Val1,Val2,....,Val15)

Also What will happen if i directly refer values in IN clause as i desribed above and i want to use NOT IN instead of IN? How to ignore NULL values using this method since they wouldn't work properly with NOT IN?

Regards
Tom Kyte
January 02, 2008 - 3:38 pm UTC

if you have a max, reasonable number - by all means, just use in

not sure what you mean in the last bit - what do you want to have happen and what do you think will happen?

they do work properly with NOT IN, I just guess you mean you would like them to work differently than ANSI said they should?

Clarification

Muhammad Riaz Shahdi, January 03, 2008 - 2:23 am UTC

Hi Tom,
Sorry for not being clear. What I meant was if I use:

WHERE <Col> IN (Val1,Val2,Val3,....Val15)

This is OK but if I change it to:

WHERE <Col> NOT IN (Val1,Val2,Val3,....Val15)

This MAY not be OK since any of Values (Val1...Val15) can be null. As far as I know (please correct me if I am wrong) I wouldn't get any record in that case (if ANY of parameter value is NULL).

Regards,
Tom Kyte
January 03, 2008 - 11:12 am UTC

You could repeat the last bound value (say you had three of them) for the rest.

where col NOT IN ( 1,2,3,3,3,3,3,3,3,3,3,3,3 )

For Muhammad Riaz Shahdi from Dubai, UAE

SeánMacGC, January 03, 2008 - 4:50 am UTC

For your 'NOT IN', you will need to use either:

a) WHERE <Col> NOT IN (NVL(Val1,'SOME IMPOSSIBLE VALUE FOR <Col>'), NVL(Val2,'SOME IMPOSSIBLE VALUE FOR <Col>')... NVL(Val5,'SOME IMPOSSIBLE VALUE FOR <Col>'))

or

b) NOT EXISTS (SELECT 1
FROM ...
WHERE (<Col> = Val1
OR <Col> = Val2
...
OR <Col> = Val5))

Tom Kyte
January 03, 2008 - 11:22 am UTC

or c

just repeat the last bind over and over....


you don't need an "impossible value" that way.
and you don't need the correlated subquery.

Last Clarification

Muhammad Riaz Shahid, January 05, 2008 - 2:32 am UTC

Hi Tom,
Can you please explain with example on how to do that?

Thanks in Advance
Tom Kyte
January 07, 2008 - 6:56 am UTC

ops$tkyte%ORA10GR2> create or replace procedure do_the_not_in_thing
  2  ( p1 in number default null,
  3    p2 in number default null,
  4    p3 in number default null,
  5    p4 in number default null,
  6    p5 in number default null,
  7    p_cursor in out sys_refcursor )
  8  as
  9  begin
 10          open p_cursor
 11          for
 12          select *
 13            from all_users
 14           where username like '%A%'
 15             and user_id not in
 16           ( p1,
 17             coalesce( p2, p1 ),
 18             coalesce( p3, p2, p1 ),
 19             coalesce( p4, p3, p2, p1 ),
 20             coalesce( p5, p4, p3, p2, p1 ) );
 21  end;
 22  /

Procedure created.

ops$tkyte%ORA10GR2> variable x refcursor
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> exec do_the_not_in_thing( 5,39, p_cursor => :x )

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> print x

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
OLAPSYS                                47 30-JUN-05
SI_INFORMTN_SCHEMA                     45 30-JUN-05
SYSMAN                                 51 30-JUN-05
MDDATA                                 50 30-JUN-05
OPS$ORA10GR2                           56 14-DEC-05
BIG_TABLE                              58 14-DEC-05
QUOTA                                  94 22-FEB-06
AQ                                    228 15-OCT-07
PERFSTAT                              148 31-MAR-06
A                                     239 19-DEC-07

10 rows selected.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create or replace type myType as table of number
  2  /

Type created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create or replace procedure do_the_not_in_thing
  2  ( p1 in number default null,
  3    p2 in number default null,
  4    p3 in number default null,
  5    p4 in number default null,
  6    p5 in number default null,
  7    p_cursor in out sys_refcursor )
  8  as
  9  begin
 10          open p_cursor
 11          for
 12          select *
 13            from all_users
 14           where username like '%A%'
 15             and user_id not in
 16           ( select *
 17               from table( myType(p1,p2,p3,p4,p5) )
 18                  where column_value is not null );
 19  end;
 20  /

Procedure created.

ops$tkyte%ORA10GR2> exec do_the_not_in_thing( 5,39, p_cursor => :x )

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> print x

USERNAME                          USER_ID CREATED
------------------------------ ---------- ---------
OLAPSYS                                47 30-JUN-05
SI_INFORMTN_SCHEMA                     45 30-JUN-05
SYSMAN                                 51 30-JUN-05
MDDATA                                 50 30-JUN-05
OPS$ORA10GR2                           56 14-DEC-05
BIG_TABLE                              58 14-DEC-05
QUOTA                                  94 22-FEB-06
AQ                                    228 15-OCT-07
PERFSTAT                              148 31-MAR-06
A                                     239 19-DEC-07

10 rows selected.

Non-equivalence

SeánMacGC, January 07, 2008 - 8:36 am UTC

Tom,
The first version of your procedure do_the_not_in_thing must have p1 (at least) as a NOT NULL, otherwise nothing will be returned.

The second version using the myType table will mimic the SQL entirely, even when all p arguments are NULL.

Tom Kyte
January 07, 2008 - 11:12 am UTC

true, thanks

Clarification

Muhammad Riaz Shahid, January 11, 2008 - 10:51 am UTC

Thanks a lot Tom/SeánMacGC,

Tom,
For simplicity can we safely use

and user_id not in
( p1,
coalesce( p2, p1 ),
coalesce( p3, p1 ),
coalesce( p4, p1 ),
coalesce( p5, p1 ) );

supposing p1 is always NOT NULL (which is the case in my scenario)?

I have tested this and it works fine.

Note: If i click on 'Preview Preview' and then click on 'Cancel', a login page appears. Is this intended behavious?I think the control should go back to question.

Regards,
Tom Kyte
January 13, 2008 - 10:53 pm UTC

that works fine, given your assumption

I'll pass on the info about the login screen, that is wrong.

This may help

Steve, January 14, 2008 - 1:04 pm UTC

I have used a technique in the past using regular expressions and a hierarchical query trick to turn a string separated by some character into a result set. I use this when I want to open a result set from a stored procedure and the user selects several items from a list that I want to filter the result set on. I am sure it has it's issues but it seems to work in a lot of situations.

:dataSeparationChar is the value used to parse the string
:concatString is the string with the separtionChar used to combine the values.

select  -- transform the comma seperated string into a result set  regexp_substr(:dataSeperationChar||:concatString||','
   , '[^'||:dataSeperationChar||']+'
    ,1
    ,level) as parsed_value
from dual
connect by level <= length(regexp_replace(:concatString, '([^'||:dataSeperationChar||'])', '')) + 1

Tom Kyte
January 14, 2008 - 3:52 pm UTC

yes, instead of regexp, I've used substr...
http://asktom.oracle.com/Misc/varying-in-lists.html

Cursor vs. Regular SQL

Michael Logan, January 16, 2008 - 9:50 am UTC

I have created everything just as you have. I'm using TOAD for development.

However the line below in a package body procedure, doesn't work. The OUT_CURSOR is a ref cursor defined in the Package Spec and is an OUT parameter on this procedure.

OPEN OUT_CURSOR FOR select * from TABLE ( cast(in_list('abc,xyz,012') as myTabletype) );

It sits there for awhile and then says "Cursor must be opened." and "Probe: timeout occurred".

However if I run just what's below in SQL it works just fine.

select * from TABLE ( cast(in_list('abc,xyz,012') as myTabletype) );

I don't get it. I'm using Oracle 9i.
Tom Kyte
January 16, 2008 - 3:56 pm UTC

try it without toad please. Use sqlplus or sqldeveloper and let me know.

maybe a problem with toad.

RE: Cursor vs. Regular SQL

Michael Logan, January 16, 2008 - 1:18 pm UTC

Nevermind. This was an issue with TOAD and not PL/SQL or Oracle.

My procedure had parameters with Date types. TOAD was passing in a date but it was using the TO_DATE function incorrectly.

Please explain NOT IN

A reader, January 25, 2008 - 4:36 pm UTC

Tom --

I am using the function described above (in_list) and it works great for IN values. However, if I use it for NOT IN, I get incorrect results. Can you please explain why NOT IN is not functioning as I thought it would? This is how I use it:

Here is your function:

create or replace 
     function in_list( p_string in varchar2 ) return MYTABLETYPESTRING
  as
      l_string        long default p_string || ',';
      l_data          MYTABLETYPESTRING := MYTABLETYPESTRING();
      n               number;
  begin
    loop
        exit when l_string is null;
         n := instr( l_string, ',' );
         l_data.extend;
         l_data(l_data.count) := 
                 ltrim( rtrim( substr( l_string, 1, n-1 ) ) );
         l_string := substr( l_string, n+1 );
    end loop;

    return l_data;
  end;
  /



Here it works great with IN:

 SELECT wfcurrent_wfde_code
 FROM kw_wfcurrent, kw_wfdocs, TABLE (in_list('200701, 200702, 200703')) split_string
 WHERE WFCURRENT_FOLDER_ID = WFDOCS_FOLDER_ID 
 AND wfcurrent_wfma_code = 3 
 AND wfcurrent_wfde_code != 250
 AND wfdocs_filter_id = split_string.COLUMN_VALUE
 AND wfdocs_filter_id not in ('200801', '200802', '200803')


If I try to use it also for NOT IN, I do not get the same results as above:

 SELECT wfcurrent_wfde_code
 FROM kw_wfcurrent, kw_wfdocs, TABLE (in_list ('200701, 200702, 200703')) t1,  TABLE (in_list ('200803, 200802, 200801'))t2
 WHERE WFCURRENT_FOLDER_ID = WFDOCS_FOLDER_ID 
 AND wfcurrent_wfma_code = 3 
 AND wfcurrent_wfde_code != 250
 AND wfdocs_filter_id = t1.COLUMN_VALUE
 AND wfdocs_filter_id not in ( t2.COLUMN_VALUE)



could you please explain?

thank you!


Tom Kyte
January 28, 2008 - 6:57 am UTC

not in (t2.column_value)

is a list with a SINGLE ELEMENT

versus

AND wfdocs_filter_id not in ('200801', '200802', '200803')

which is a list of three elements - I fail to see how you are comparing the two as "equivalent" - they are so far from being so??!?!?


you would compare:

FROM kw_wfcurrent, kw_wfdocs, TABLE (in_list ('200701, 200702, 200703')) t1,
TABLE (in_list ('200803, 200802, 200801'))t2
WHERE WFCURRENT_FOLDER_ID = WFDOCS_FOLDER_ID
AND wfcurrent_wfma_code = 3
AND wfcurrent_wfde_code != 250
AND wfdocs_filter_id = t1.COLUMN_VALUE
AND wfdocs_filter_id not in ( select * from TABLE(in_list ('200701, 200702, 200703')) )

maybe - but not what you have.

MAX/MIN

Deepak, February 24, 2008 - 10:53 am UTC

Hi Tom,

Please do not mind for asking a simple question.

I have many numeric variables in a PL/SQL procedure.

I would like to compute the MAX/MIN of the values.

I know we can use

select min(val) from (
select var1 val from dual
union all
select var1 val from dual
...
)

But is there any other and more efficient method?


Tom Kyte
February 24, 2008 - 12:00 pm UTC

totally insufficient details here. If they were just willy nilly in a bunch of variables, it would be:

ops$tkyte%ORA10GR2> declare
  2          a       number := dbms_random.random;
  3          b       number := dbms_random.random;
  4          c       number := dbms_random.random;
  5          mx      number;
  6  begin
  7          mx := greatest( a,b,c );
  8          dbms_output.put_line( 'a = ' || a );
  9          dbms_output.put_line( 'b = ' || b );
 10          dbms_output.put_line( 'c = ' || c );
 11          dbms_output.put_line( 'mx= ' || mx);
 12  end;
 13  /
a = 1087683771
b = -1601966569
c = 1162115543
mx= 1162115543

PL/SQL procedure successfully completed.

rwnum >=0 and/or hint materialize for subquery does not work

Andriy, March 23, 2008 - 3:21 pm UTC

Hi Tom
You have said that rownum >=0 or materialize hint will materialize subquery and function will be called only one time, but this is does not happened inmy test case.
Why ? and how to materialize subquery to avoid multiple time of function execution ?

See my test case
PS hint used to force nested loop is used to show of multiple times calls of function

SQL> 
SQL> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bi
PL/SQL Release 10.2.0.4.0 - Production
CORE 10.2.0.4.0 Production
TNS for Linux: Version 10.2.0.4.0 - Production
NLSRTL Version 10.2.0.4.0 - Production

SQL> 
SQL> create or replace type str2tblType as table of varchar2(30);
  2   /

Type created.

SQL> 
SQL> create or replace
  2    function str2tbl( p_str in varchar2, p_delim in varchar2
  3    default ',' ) return str2tblType
  4    deterministic authid current_user PIPELINED
  5    as
  6      l_str      long default p_str || p_delim;
  7      l_n        number;
  8    begin
  9      dbms_application_info.set_client_info( userenv('client_info')+1 );
 10      loop
 11        l_n := instr( l_str, p_delim );
 12        exit when (nvl(l_n,0) = 0);
 13        pipe row( ltrim(rtrim(substr(l_str,1,l_n-1))) );
 14        l_str := substr( l_str, l_n+1 );
 15      end loop;
 16      return;
 17    end;
 18    /

Function created.

SQL> 
SQL> drop table emp2;

Table dropped.

SQL>  create table emp2 as
  2    select object_name ename, max(object_id) empno, max(object_type) ot,
  3      max(created) created, rpad( '*', 80, '*') data
  4    from all_objects
  5    group by object_name;

Table created.

SQL> 
SQL> alter table emp2 add constraint emp2_pk primary key(empno);

Table altered.

SQL> 
SQL> create index emp2_ename on emp2(ename);

Index created.

SQL> 
SQL> analyze table emp2 compute statistics for table for all indexes for all indexed columns;

Table analyzed.

SQL> 
SQL> variable in_list varchar2(255)
SQL> 
SQL> exec :in_list := 'DBMS_PIPE,DBMS_OUTPUT,UTL_FILE';

PL/SQL procedure successfully completed.

SQL> 
SQL> exec dbms_application_info.set_client_info(0);

PL/SQL procedure successfully completed.

SQL> 
SQL> 
SQL> 
SQL> set autotrace traceonly;
SQL>  select * from emp2
  2   where ename in (
  3      select /*+ materialize cardinality(t 10 ) NL_SJ*/ * from TABLE(cast( str2tbl( :in_list ) as str2tblType) ) t
  4      where rownum >= 0
  5   );


Execution Plan
----------------------------------------------------------
Plan hash value: 2135364371

--------------------------------------------------------------------------------------------------
| Id  | Operation                             | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                      |          |     1 |   191 |   658K  (1)| 02:11:41 |
|   1 |  NESTED LOOPS SEMI                    |          |     1 |   191 |   658K  (1)| 02:11:41 |
|   2 |   TABLE ACCESS FULL                   | EMP2     | 27311 |  3440K|   116   (1)| 00:00:02 |
|*  3 |   VIEW                                | VW_NSO_1 |     1 |    62 |    24   (0)| 00:00:01 |
|   4 |    COUNT                              |          |       |       |            |          |
|*  5 |     FILTER                            |          |       |       |            |          |
|   6 |      COLLECTION ITERATOR PICKLER FETCH| STR2TBL  |       |       |            |          |
--------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter("ENAME"="COLUMN_VALUE")
   5 - filter(ROWNUM>=0)


Statistics
----------------------------------------------------------
        138  recursive calls
          0  db block gets
        567  consistent gets
          0  physical reads
          0  redo size
        778  bytes sent via SQL*Net to client
        337  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          3  rows processed

SQL> 
SQL> set autotrace off
SQL> select userenv('CLIENT_INFO') from dual;

USERENV('CLIENT_INFO')
----------------------------------------------------------------
27311

SQL> 
SQL> 
SQL> select count(*) from emp2;

  COUNT(*)
----------
     27311

SQL> 
SQL> spool off


Tom Kyte
March 24, 2008 - 11:21 am UTC

why the NL_SJ

anyway, try this

with data as
(select /*+ MATERIALIZE */ ..... table() )
select * 
  from emp
 where ename in (select * from data)

using a cursor on with data as (select /*+ materialize cardinality...

sara, March 25, 2008 - 11:19 am UTC

How to use a cursor with this?
the select alone works...
with data
as
(select /*+ materialize cardinality(x,10) */ * from TABLE(str2tbl('ra,33')) x )
select col1
from temp t
where (select 1
from data
where instr(t.col1,data.column_value)>0
and rownum = 1) = 1;


DECLARE
l_ref sys_refcursor;
p_str VARCHAR2(4000):= 'dog,cat,rat,horse';
l_data myTableType := myTableType();
p_delim VARCHAR2(1) := ',';
l_str long default p_str || p_delim;
l_n number;
l_cnt number;
l_id number;
BEGIN
loop
l_n := instr( l_str, p_delim );
exit when (nvl(l_n,0) = 0);
l_data.extend;
l_data(l_data.count) := UPPER(ltrim(rtrim(substr(l_str,1,l_n-1))));
l_str := substr( l_str, l_n+1 );
END LOOP;
dbms_output.put_line(l_data.count);
open l_ref for
with data
as
(select /*+ materialize cardinality(x,10) */ * from TABLE(str2tbl('ra,33')) x )
select col1
from temp t
where (select 1
from data
where instr(t.col1,data.column_value)>0
and rownum = 1) = 1;
dbms_output.put_line(l_ref%ROWCOUNT);
/*LOOP
fetch l_ref into l_id;
EXIT WHEN l_ref%NOTFOUND;
DBMS_OUTPUT.PUT_LINE(l_id);
END LOOP;*/
END;
/

Thanks

Sara
Tom Kyte
March 26, 2008 - 8:26 am UTC

your code ran for me - not sure what you mean.

why oracle can call table function few times

Andriy, April 03, 2008 - 11:23 am UTC

Can you explain why Oracle can call pipeline function few time ? why it doesnt cache it or some other way avoid calling function few time?

May be we need or have some way to produce to oracle a cost of each call to our PIPILINE function ?

Using pkg define SQL types in Pipelined functions

ali, April 21, 2008 - 6:55 am UTC

Really useful stuff as ever, but I am intrigued as to why I cannot use the 'implicit' sql types when defined in pkg as per the 'foo' example.

totally understand why the data type must be sql and not pl/sql, but saw the example and system generated types and would really like to understand where I am going wrong.

On 9.2 I get:
ORA-00600: internal error code, arguments: [15419], [severe error during PL/SQL execution], [], [], [], [], [], []
ORA-06544: PL/SQL: internal error, arguments: [pvm.c:pfrbs_bind_scalar1()], [], [], [], [], [], [], []
ORA-06553: PLS-801: internal error [pvm.c:pfrbs_bind_scalar1()]
On 10.2 I get:
ORA-00902: invalid datatype

Here is my hopefully, small, concise yet 100% complete example:

set serverout on

drop type my_array;
/
drop table t;
/

create or replace type my_array is table of number;
/

create table t (x int);

insert into t values (1);
insert into t values (2);
insert into t values (3);
commit;

select * from t;

create or replace package pkg as
type my_array2 is table of number;
function foo (ptab my_array) return my_array pipelined;
function foo2 (ptab my_array2) return my_array2 pipelined;
procedure do(i int) ;
end pkg;
/
create or replace package body pkg as

function foo (ptab my_array) return my_array pipelined as
begin
dbms_output.put_line('foo called');
for i in ptab.first..ptab.last
loop
dbms_output.put_line('foo ('||i||')='|| ptab(i));
pipe row (ptab(i));
end loop;
return;
end foo;

function foo2(ptab my_array2) return my_array2 pipelined as
begin
dbms_output.put_line('foo2 called');
for i in ptab.first..ptab.last
loop
dbms_output.put_line('foo2 ('||i||')='|| ptab(i));
pipe row (ptab(i));
end loop;
return;
end foo2;

procedure do(i int) is
vtab my_array:=my_array();
vtab2 my_array2:=my_array2();
begin
if i = 1 then
dbms_output.put_line('started');
vtab.extend;
vtab(1):=1;
vtab.extend;
vtab(2):=3;
for c in (select x from t where x in (
select column_value from table(pkg.foo(vtab)))
) loop
dbms_output.put_line(c.x);
end loop;
dbms_output.put_line('ended');
else
dbms_output.put_line('started2');
vtab2.extend;
vtab2(1):=1;
vtab2.extend;
vtab2(2):=3;
for c2 in (select x from t where x in (
select column_value from table(pkg.foo2(vtab2)))
) loop
dbms_output.put_line(c2.x);
end loop;
dbms_output.put_line('2ended');
end if;
end do;
end pkg;
/

begin
pkg.do(1);
end;
/
begin
pkg.do(2);
end;
/

Tom Kyte
April 23, 2008 - 4:45 pm UTC

because sql can only see sql types, it cannot and will not see plsql types. That is the reason. Plsql types are for - plsql only.

ali, April 24, 2008 - 8:51 am UTC

I was interested in your response earlier:
-------------------------------------------
but don't think you got around anything:

OBJECT_TYPE OBJECT_NAME S TABLESPACE_NAME
------------ ------------------------------ - ------------------------------
PACKAGE DEMO_PKG

PACKAGE BODY DEMO_PKG

TYPE SYS_PLSQL_41330_9_1
SYS_PLSQL_41330_DUMMY_1


you have two types created automagically for you in this case, instead of just one
-------------------------------------------

and wanted to understand why I couldn't specify the type in the package and rely on oracle creating the system generated types for me.

Tom Kyte
April 28, 2008 - 11:45 am UTC

you can - and no one said you cannot, but you haven't reduced the number of objects in the schema - so, I ask you "what was the point"...

Now you have this ugly pair of system generated names that will have people asking you over and over "what is this SYS_PLSQL_41330_DUMMY_1 thing"

or in production when something doesn't work "hey, in test we had SYS_PLSQL_41330_DUMMY_1 and in prod we have SYS_PLSQL_54321_DUMMY_1 - that must be the problem, we have different stuff" (thus wasting your day chasing nothing down a big rathole)



dynamic cur with object type

sara, May 06, 2008 - 12:07 pm UTC

Hi Tom,

in 8i,

is it possible to have a dynamic cur like the following?

declare
l_author obj_author_typ ;
begin
OPEN p_generic_cursor FOR
'SELECT * FROM THE ( SELECT CAST( ' || l_author || ' AS ' || obj_author_typ) FROM DUAL) ' ;
end;

where l_author is
CREATE OR REPLACE TYPE author_typ
AS OBJECT (
col1 NUMBER
, col2 NUMBER
, col3 NUMBER
);
/

CREATE OR REPLACE TYPE obj_author_typ AS TABLE OF author_typ;
/

Thanks in advance Tom...
Tom Kyte
May 07, 2008 - 12:56 am UTC

in no release would you concatenate an object type in like this:

SELECT CAST( ' || l_author || ' AS '

think about it, what would that do? You cannot concatenate an object into a string like that. You have to BIND

extended in_list function

Gypsy, May 06, 2008 - 6:52 pm UTC

On Oracle 9i via T.O.A.D. I found the original in_list function didn't return the last set of values. I added the "if l_idx = 0" section and all values are retrieved.

CREATE OR REPLACE FUNCTION inList( p_string IN VARCHAR2 )
RETURN varchar2_list
AS
l_data varchar2_list := varchar2_list();
l_string VARCHAR2(32767) := p_string ;
l_idx NUMBER :=1;
t_data VARCHAR2(32767);
BEGIN
LOOP
l_idx := instr( l_string, ',' );
l_data.EXTEND;
l_data(l_data.LAST):= TRIM( SUBSTR( l_string, 1,l_idx-1));
l_string := SUBSTR( l_string, l_idx+1 );

-- get last piece of data
if l_idx = 0
then
l_data(l_data.LAST) := TRIM( SUBSTR( l_string, 1));
end if;


EXIT WHEN l_idx = 0 ;
END LOOP;
RETURN l_data;
END;

Another Variable IN List question?

Maverick, May 09, 2008 - 11:37 am UTC

Tom, is there a way to change this query
   select * from table A
     where 
          (col_a in (select list_col from table B)
           OR
           col_b in (select list_col from table B)
           OR
           col_c in (select list_col from table B)
          )    


in any other way? I do not want to use so many OR's. I have a requirement to check if any of these columns [there are 5 of them currently] exists in that list?

Thanks for your valuable time

connect by level and in list

Car Elcaro, June 10, 2008 - 1:47 am UTC

Hi Tom,

I have a problem with connect by level clause. This is not the real problem but a simplified version of problem. Here is the setup.
create table t
(
  nuf integer, --stand for Non Unique Field
  lid varchar2(10) --List of ID
);

insert into t values (1,'a,b,c');
insert into t values (1,'e,f');
insert into t values (2,'g,h');

myself@orcl> select * from v$version;

BANNER
-------------------------------------------------------------------------------

Oracle Database 11g Enterprise Edition Release 11.1.0.6.0 - Production
PL/SQL Release 11.1.0.6.0 - Production
CORE    11.1.0.6.0      Production
TNS for Linux: Version 11.1.0.6.0 - Production
NLSRTL Version 11.1.0.6.0 - Production

myself@orcl> select * from t;

       NUF LID
---------- ----------
         1 a,b,c
         1 e,f
         2 g,h

Connect by query against that table.
select level, nuf, substr(replace(lid,',',''),(level-1)+1,1) id 
from t
where nuf = 2
connect by level <= length(translate(lid,',abcdefghijklmnopqrstuvwxyz',','))+1
order by level


Output
         
     LEVEL        NUF I
---------- ---------- -
         1          2 g
         2          2 h
         2          2 h
         2          2 h


I confuse with connect by prior here, because in my understanding that query will result output like this.

     LEVEL        NUF I
---------- ---------- -
         1          2 g
         2          2 h


Please help me to
1. explain why the connect by clause resulting that answer (Three of level 2) ?
2. write sql statement for correcting so that for all record of that table will result the following.

     LEVEL        NUF I
---------- ---------- -
         1          1 a
         2          1 b
         3          1 c
         1          1 e
         2          1 f
         1          2 g
         2          2 h


PS for no 2. of course I can add distinct clause before level column but I don't get the logic for how this connect by level could resulting duplicate level.

Many thanks Tom.
Tom Kyte
June 10, 2008 - 7:51 am UTC

it is always so sad to see the same data processing mistakes made time and yet time again. Here we have a classic one - storing the ubiquitous "comma separated list of values" - and then immediately wishing we had good old relational data instead.

1) 1. explain why the connect by clause resulting that answer (Three of level 2) ?

ops$tkyte%ORA11GR1> select level, nuf, substr(replace(lid,',',''),(level-1)+1,1) id ,
  2          length(translate(lid,',abcdefghijklmnopqrstuvwxyz',','))+1 len,
  3          substr( sys_connect_by_path( nuf||', "'||lid||'"', ' - ' ), 4 ) scbp
  4  from t
  5  where nuf = 2
  6  connect by level <= length(translate(lid,',abcdefghijklmnopqrstuvwxyz',','))+1
  7  order by level
  8  /

     LEVEL        NUF I        LEN SCBP
---------- ---------- - ---------- ------------------------------
         1          2 g          2 2, "g,h"
         2          2 h          2 2, "g,h" - 2, "g,h"
         2          2 h          2 1, "a,b,c" - 2, "g,h"
         2          2 h          2 1, "e,f" - 2, "g,h"



you did a connect by level <= number. You did not connect by anything else. So, every row connects with every other row.

2, "g,h" connected with itself. It connected with 1, "a,b,c", it connected with 1, "e,f".


2)


ops$tkyte%ORA11GR1> select nuf, column_value
  2    from (select nuf, ','||lid||',' txt from t where nuf = 2) t,
  3         table( cast( multiset( select trim( substr (txt, instr (txt, ',', 1, level  ) + 1,
  4                                       instr (txt, ',', 1, level+1) - instr (txt, ',', 1, level) -1 ) )
  5                                  from dual
  6                               connect by level <= length(txt)-length(replace(txt,',',''))-1 ) as sys.odcivarchar2list ) )
  7  /

       NUF COLUMN_VAL
---------- ----------
         2 g
         2 h

ops$tkyte%ORA11GR1> select nuf, column_value
  2    from (select nuf, ','||lid||',' txt from t ) t,
  3         table( cast( multiset( select trim( substr (txt, instr (txt, ',', 1, level  ) + 1,
  4                                       instr (txt, ',', 1, level+1) - instr (txt, ',', 1, level) -1 ) )
  5                                  from dual
  6                               connect by level <= length(txt)-length(replace(txt,',',''))-1 ) as sys.odcivarchar2list ) )
  7  /

       NUF COLUMN_VAL
---------- ----------
         1 a
         1 b
         1 c
         1 e
         1 f
         2 g
         2 h

7 rows selected.



Question

Mathew, July 16, 2008 - 5:37 am UTC

Dear Tom,
iam facing some problem in the Oracle Dtabase 11g while i issue the str2tbl function inside the select query.The same function was worked in our 9i database .In 11g its giving the error "Expected number but tbl_type"
in this error tbl_type is the a TABLE Type
iam expecting your reply
Regards
mathew
Tom Kyte
July 16, 2008 - 10:09 am UTC

I'm awaiting your cut and paste from sqlplus so we can see how you bound, what you are doing.

Nearly impossible to search for the THE keyword

Mark Brady, November 06, 2008 - 4:38 pm UTC

Every search eliminates it until you quote it and then you're just sad.

Can you link the documentation of THE or tell me what it's called?
Tom Kyte
November 11, 2008 - 2:35 pm UTC

it is deprecated, ignore it, it is there for backwards compatibility but no longer 'exists'


TABLE is the word now.

And good luck searching for that as well.


but here is the link, even mentions "the"

http://docs.oracle.com/docs/cd/B19306_01/server.102/b14200/statements_10002.htm#i2104990

Sachin, November 14, 2008 - 8:13 am UTC


Hi Tom,

I think, this is best query to deal such issue
but only applicable above oracle 9i version.


select regexp_substr(str, '[^, ]+', 1, level) Words

from (select '1,2,3' str from dual)

connect by regexp_substr(str, '[^, ]+', 1, level) is not null;


Regards
Sachin

XMLTABLE

Yuan, December 11, 2008 - 1:20 pm UTC

Tom, I'm trying to accomplish the same thing you accomplished with your inlist function, but using XMLTABLE instead.  I was successful, but I do not know how to get the optimizer to use an index.  Here's an example using the Emp table.

SQL*Plus: Release 10.2.0.4.0 - Production on Thu Dec 11 13:11:11 2008

Copyright (c) 1982, 2007, Oracle.  All Rights Reserved.


Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL> set autotrace trace explain
SQL> SELECT * FROM Emp WHERE EmpNo IN (7521);

Execution Plan
----------------------------------------------------------
Plan hash value: 2949544139

--------------------------------------------------------------------------------------
| Id  | Operation                   | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |        |     1 |    87 |     1   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| EMP    |     1 |    87 |     1   (0)| 00:00:01 |
|*  2 |   INDEX UNIQUE SCAN         | PK_EMP |     1 |       |     1   (0)| 00:00:01 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("EMPNO"=7521)

SQL> SELECT * FROM Emp
  2  WHERE EmpNo IN (SELECT EmpNo
  3                  FROM XMLTABLE('/Emps/Emp'
  4                                PASSING XMLTYPE('<Emps><Emp EmpNo="7521" /></Emps>')
  5                                COLUMNS EmpNo VARCHAR2(10) PATH '@EmpNo'));

Execution Plan
----------------------------------------------------------
Plan hash value: 1883281025

-------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name                   | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |                        |     1 |    89 |    14   (8)| 00:00:01 |
|*  1 |  HASH JOIN SEMI                    |                        |     1 |    89 |    14   (8)| 00:00:01 |
|   2 |   TABLE ACCESS FULL                | EMP                    |    14 |  1218 |     2   (0)| 00:00:01 |
|   3 |   COLLECTION ITERATOR PICKLER FETCH| XMLSEQUENCEFROMXMLTYPE |       |       |            |          |
-------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("EMPNO"=TO_NUMBER(CAST(SYS_XQ_UPKXML2SQL(SYS_XQEXVAL(SYS_XQEXTRACT(VALUE(KOKBF$),'/Emp/
              @EmpNo')),50,1,2) AS VARCHAR2(10) )))

Note
-----
   - dynamic sampling used for this statement

I actually got it to use the index by adding a first_rows hint.....

SQL> SELECT /*+ FIRST_ROWS */ * FROM Emp
  2  WHERE EmpNo IN (SELECT EmpNo
  3                  FROM XMLTABLE('/Emps/Emp'
  4                                PASSING XMLTYPE('<Emps><Emp EmpNo="7521" /></Emps>')
  5                                COLUMNS EmpNo VARCHAR2(10) PATH '@EmpNo'));

Execution Plan
----------------------------------------------------------
Plan hash value: 422873110

--------------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name                   | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |                        |   255 | 22695 |   267   (1)| 00:00:05 |
|   1 |  NESTED LOOPS                       |                        |   255 | 22695 |   267   (1)| 00:00:05 |
|   2 |   SORT UNIQUE                       |                        |       |       |            |          |
|   3 |    COLLECTION ITERATOR PICKLER FETCH| XMLSEQUENCEFROMXMLTYPE |       |       |            |          |
|   4 |   TABLE ACCESS BY INDEX ROWID       | EMP                    |     1 |    87 |     1   (0)| 00:00:01 |
|*  5 |    INDEX UNIQUE SCAN                | PK_EMP                 |     1 |       |     0   (0)| 00:00:01 |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("EMPNO"=TO_NUMBER(CAST(SYS_XQ_UPKXML2SQL(SYS_XQEXVAL(SYS_XQEXTRACT(VALUE(KOKBF$),'/Emp/@
              EmpNo')),50,1,2) AS VARCHAR2(10) )))

Note
-----
   - dynamic sampling used for this statement

But then even that doesn't help when I want to aggregate.....

SQL> SELECT /*+ FIRST_ROWS */ AVG(Sal) FROM Emp
  2  WHERE EmpNo IN (SELECT EmpNo
  3                  FROM XMLTABLE('/Emps/Emp'
  4                                PASSING XMLTYPE('<Emps><Emp EmpNo="7521"/></Emps>')
  5                                COLUMNS EmpNo VARCHAR2(10) PATH '@EmpNo'));

Execution Plan
----------------------------------------------------------
Plan hash value: 1764866534

--------------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name                   | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |                        |     1 |    28 |    14   (8)| 00:00:01 |
|   1 |  SORT AGGREGATE                     |                        |     1 |    28 |            |          |
|*  2 |   HASH JOIN SEMI                    |                        |     1 |    28 |    14   (8)| 00:00:01 |
|   3 |    TABLE ACCESS FULL                | EMP                    |    14 |   364 |     2   (0)| 00:00:01 |
|   4 |    COLLECTION ITERATOR PICKLER FETCH| XMLSEQUENCEFROMXMLTYPE |       |       |            |          |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("EMPNO"=TO_NUMBER(CAST(SYS_XQ_UPKXML2SQL(SYS_XQEXVAL(SYS_XQEXTRACT(VALUE(KOKBF$),'/Emp/@
              EmpNo')),50,1,2) AS VARCHAR2(10) )))

Note
-----
   - dynamic sampling used for this statement

Tom Kyte
December 11, 2008 - 9:08 pm UTC

Thanks!

Yuan, December 12, 2008 - 9:51 am UTC

Awesome! That's exactly what I need.

Instead of creating the in_list function ..

Nicole, January 05, 2009 - 4:39 pm UTC

Hi Tom, regarding the original question, I also needed something like this and I tried the following:

create or replace type in_list_t as table of varchar2(100);
/
create or replace type in_list_v as varray(10) of varchar2(100);
/

select * from all_users where username in
(select pl.column_value from table(cast(in_list_v('SYS', 'SYSTEM') as in_list_t)) pl)
/

or to use a function and to pass a parameter:

create or replace function f_test
(
p_in in_list_v
)
return number
is
ncount number;

begin
select count(*) into ncount
from sys.all_users
where username in (select pl.column_value from table(cast(p_in as in_list_t)) pl);
return ncount;
end;
/
show err

select f_test(in_list_v('SYS', 'SYSTEM')) from dual
/

drop type in_list_t;
drop type in_list_v;
drop function f_test;

What do you think about this approach?
Thanks.
Tom Kyte
January 05, 2009 - 4:43 pm UTC

http://asktom.oracle.com/Misc/varying-in-lists.html


shows a way to do this without any functions.


but of course you can just use a static collection like that:

select * from all_users where username in
(select pl.column_value from table(cast(in_list_v('SYS', 'SYSTEM') as
in_list_t)) pl)
/


but - it begs the question, why not just:


select * from all_suers where username in ( 'SYS', 'SYSTEM' );

?

Nicole, January 05, 2009 - 6:30 pm UTC

I need to insert in a table tb1 for each record meeting a certain criteria from a second table tb2 multiple records for different periods of time, something like:

create or replace type in_list_t as table of varchar2(100);
/

create or replace type in_list_v as varray(10) of varchar2(100);
/

create table tb1(username varchar2(30), period number(3), description varchar(30))
/

insert into tb1(
username,
period,
description
)
select
username,
pl.column_value period,
'Text - '||pl.column_value||' days' description
from all_users tb2, table(cast(in_list_v(30,60,90,120,180) as in_list_t)) pl
where username in ('SYS', 'SYSTEM')
/

commit
/


Is there a better way of doing this?
Thanks for your help..
Tom Kyte
January 05, 2009 - 6:55 pm UTC

  1  with data as (select 30*rownum n from dual connect by level <= 4 union all select 180 from dual)
  2  select username, n period from all_users, data
  3* where username in ( 'SYS', 'SYSTEM' )
ops$tkyte%ORA10GR2> /

USERNAME                           PERIOD
------------------------------ ----------
SYS                                    30
SYS                                    60
SYS                                    90
SYS                                   120
SYS                                   180
SYSTEM                                 30
SYSTEM                                 60
SYSTEM                                 90
SYSTEM                                120
SYSTEM                                180

10 rows selected.

Thank you!

Nicole, January 06, 2009 - 3:00 pm UTC

I like this very much, Tom, thank you.

using with inline table column

Gerard, February 11, 2009 - 8:14 am UTC

Can i use the obj_tst in a in view such as
select * from tmptable where executable in (select obj_tst from test)

create or replace type application_exec_type as object
(
executable varchar2(256),
describt varchar2(256),
version varchar2(25),
constructor function application_exec_type(p_name varchar
);
/
create or replace type application_exec_type_tbl as table of application_exec_type;
/

create table test (
col1 number,
col2 number,
obj_tst application_exec_type_tbl)
nested table obj_tst store as obj_tst_table;


Tom Kyte
February 11, 2009 - 12:26 pm UTC

what you have to think about here is that each row of test has a 'virtual table' associated with it (that is the goal of the nested table)

if you use a nested table, you are basically saying "i have a weak entity, one that only exists in the context of its parent, I will never query that weak entity except in the presence of its parent"

But you seem to want to - which means, you do not really have a weak entity, you have a string entity and you want a conventional parent child relationship (like DEPT is to EMP, you want to query EMP even without accessing DEPT).


we could use table unnesting - but basically your data model is wrong, you want a real table there.

Multiple column inlists

C, April 03, 2009 - 5:36 am UTC

I need to delete data from a number of tables based on values obtained from a different table. I have provided a simplified version of where I'm up to below. 

In reality test_a is a large table from which I'm going to select approx 1000 rows. As it's a large table I don't want to have to access it mutliple times.

What I actually need to do is to change the procedure below to delete from test_c using the values from test_a.col_2. 
I have tried creating a type as a table of objects but it fails when I try to bulk collect into it. If I use PL/SQL definitions I can do the bulk collect but the deletes fail as it isn't a SQL datatype. Is it possible to do this or woud I be better using a gtt? 

CREATE TABLE test_a
(col_1  NUMBER(1),
 col_2  NUMBER(1),
 col_3  NUMBER(1));

CREATE TABLE test_b
(col_1  NUMBER(1),
 col_2  NUMBER(1));

CREATE TABLE test_c
(col_1  NUMBER(1),
 col_2  NUMBER(1));

INSERT INTO test_a VALUES (1, 1, 1);
INSERT INTO test_a VALUES (2, 2, 2);
INSERT INTO test_a VALUES (3, 3, 3);

INSERT INTO test_b VALUES (1, 1);
INSERT INTO test_b VALUES (2, 2);
INSERT INTO test_b VALUES (3, 3);

INSERT INTO test_c VALUES (1, 1);
INSERT INTO test_c VALUES (2, 2);
INSERT INTO test_c VALUES (3, 3);

CREATE OR REPLACE TYPE myTableType AS TABLE OF NUMBER(1);
/

CREATE OR REPLACE PROCEDURE myTest
AS        
        l_data    myTableType;          
BEGIN
        SELECT col_1 BULK COLLECT INTO l_data
          FROM test_a
         WHERE col_1 < 3;

   DELETE FROM test_b WHERE col_1 IN
  (SELECT * from TABLE(l_data));

 DELETE FROM test_c WHERE col_1 IN
 (SELECT * from TABLE(l_data)); 
END;
/

exec myTest;



Failed Attempts:

CREATE OR REPLACE TYPE myObject AS OBJECT (col1 NUMBER(1), col2  NUMBER(1));
/
CREATE OR REPLACE TYPE myTableType AS TABLE OF myobject;
/

CREATE OR REPLACE PROCEDURE myTest
AS        
        l_data    myTableType;             
BEGIN
        SELECT col_1, col_2 BULK COLLECT INTO l_data
          FROM test_a;

   DELETE FROM test_b WHERE col_1 IN
  (SELECT col1 from TABLE(l_data));

 DELETE FROM test_c where col_1 IN
 (SELECT col2 from TABLE(l_data)); 
END;
/

Warning: Procedure created with compilation errors.

SQL> show errors
Errors for PROCEDURE MYTEST:

LINE/COL ERROR
-------- --------------------------------------------------
5/9      PL/SQL: SQL Statement ignored
6/11     PL/SQL: ORA-00947: not enough values

CREATE OR REPLACE PROCEDURE myTest
AS   
 TYPE myTableRowType IS RECORD (col1  test_a.col_1%TYPE, col2  test_a.col_2%TYPE);      
        TYPE myTableType2 IS TABLE OF myTableRowType; 
 l_data myTableType2;         
BEGIN
        SELECT col_1, col_2 BULK COLLECT INTO l_data
          FROM test_a;

   DELETE FROM test_b WHERE col_1 IN
  (SELECT col1 from TABLE(l_data));

 DELETE FROM test_c where col_1 IN
 (SELECT col2 from TABLE(l_data)); 
END;
/

Warning: Procedure created with compilation errors.

SQL> show errors
Errors for PROCEDURE MYTEST:

LINE/COL ERROR
-------- --------------------------------------------------
10/4     PL/SQL: SQL Statement ignored
11/21    PL/SQL: ORA-22905: cannot access rows from a non-nested table item
11/27    PLS-00642: local collection types not allowed in SQL statements
13/2     PL/SQL: SQL Statement ignored
14/20    PL/SQL: ORA-22905: cannot access rows from a non-nested table item
14/26    PLS-00642: local collection types not allowed in SQL statements


Tom Kyte
April 03, 2009 - 8:00 am UTC

ops$tkyte%ORA10GR2> CREATE OR REPLACE PROCEDURE myTest
  2  AS
  3          l_data    myTableType;
  4  BEGIN
  5          SELECT <b>myObject(col_1, col_2)</b> BULK COLLECT INTO l_data
  6            FROM test_a;
  7
  8        DELETE FROM test_b WHERE col_1 IN
  9       (SELECT col1 from TABLE(l_data));
 10
 11      DELETE FROM test_c where col_1 IN
 12      (SELECT col2 from TABLE(l_data));
 13  END;
 14  /

Procedure created.

Multiple column inlists

C, April 03, 2009 - 10:21 am UTC

That works perfectly now. Thanks.

Plan changes to full table scan with in_list()

A reader, July 13, 2009 - 4:50 pm UTC

Hi Tom,

This is a very useful page. Before using the in_list() approach, the query is using index range scan but after using the in_list() the query is doing a full table scan. Can you please explain. Also, how to avoid full table scan in this scenario, with a small number of items in the in list ?

Test case :

create table test as select * from all_objects;

create index idx_name on test(object_name);

analyze table test compute statistics for table for all indexes for all indexed columns;

select * from test where object_name in (:x);

-- Uses the index idx_name

select *
from test
where object_name in (select *
from the (select cast (in_list (:x) as string_type)
from dual))
-- Does a full table scan.

Thanks,
r-a-v-i


Java beats the function technique

A reader, July 15, 2009 - 12:36 pm UTC

Hi Tom,

Applying the cardinality hint and rownum >=0 in the sub query improved the performance of the query.

Here is another approach using Java. Say if the number of items in the in list is 500. Then what we do is divide the big list into 10 batches, for each batch prepare a PreparedStatement with the sql like this: select * from t where col1 in (?,?,? ....?) [50 of ?]. Then bind the 50 values onto the PreparedStatement, execute the query. So, in this case we would execute the query 10 times for 10 batches with different in values. Store the results of each execution in to a collection and finally return the collection, once we are done with all the 10 batches.
I was under the impression that the function approach would be quite faster than the above mentioned java approach.
But surprisingly, the java approach beats the function approach by atleast 50 - 100 ms.
Any thoughts ?

Tom Kyte
July 15, 2009 - 12:46 pm UTC

show us the numbers.

how did you measure it to show a "1/10th to 5/100th of a second difference"?????

what where you measuring
how did you measure
how many times did you measure

got the tkprofs???

Java beats the function technique

A reader, July 15, 2009 - 3:23 pm UTC

>>>>>>>>>>> show us the numbers.

Ran the attached java code .... which prints the information :

For 99 items in the list :

>>>>>>>>>>> Function Test <<<<<<<<<<<<<<<<<
# : 99 | Function >>> : Time taken : 203 ms

>>>>>>>>>>> Java Test <<<<<<<<<<<<<<<<<
Executed query : 1 times.
# : 99 | Java >>> : Time taken : 47 ms


For 802 items in the lis :

>>>>>>>>>>> Function Test <<<<<<<<<<<<<<<<<
# : 802 | Function >>> : Time taken : 359 ms
>>>>>>>>>>> Java Test <<<<<<<<<<<<<<<<<
Executed query : 1 times.
Executed query : 2 times.
Executed query : 3 times.
Executed query : 4 times.
Executed query : 5 times.
Executed query : 6 times.
Executed query : 7 times.
Executed query : 8 times.
Executed query : 9 times.
# : 802 | Java >>> : Time taken : 344 ms

>>>>>>>>>>> how did you measure it to show a "1/10th to 5/100th of a second difference"?????

long startTime = System.currentTimeMillis();
.....
.....
long endTime = System.currentTimeMillis() - startTime;

>>>>>>>>>>> what where you measuring

Pls refer the code..basically entire execution time from Java right from PreparedStatement creation till retrieving the results.
how did you measure

>>>>>>>>>>> how many times did you measure

Ran atleast 5 to 6 times and the difference was almost similar to the above

>>>>>>>>>>> got the tkprofs???

Sorry, I don't have access to get tkprofs. Please execuse me for this. I know this is insufficient information.

create table test as select * from all_objects;

select object_id from test;

create index idx_id on test(object_id);

analyze table test compute statistics for table for all indexes for all indexed columns;

Here are the plans :

For the query with the function :

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=ALL_ROWS 1 31
NESTED LOOPS 1 133 31
VIEW SYS.VW_NSO_1 1 129 29
HASH UNIQUE 1 2
COUNT
FILTER
COLLECTION ITERATOR PICKLER FETCH .IN_LIST
INDEX RANGE SCAN U0.IDX_ID 1 4 1


For the query without the function :

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=ALL_ROWS 1 1
INDEX RANGE SCAN U0.IDX_ID 1 4 1

Looking at the plans the both use index range scan.

Here is the sample java code ... (I have presented only the necessary code here...it won't compile).


import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.util.ArrayList;
import java.util.Arrays;
import java.util.Collection;
import java.util.Collections;
import java.util.Hashtable;
import java.util.List;
import java.util.Vector;

public class TestDynamicInList {
static Connection conn;
String data = "30,83,138,152,227,244,247,311,335,380,472,484,555,604,647,665,670,787,833,851,1253,1433,1451,1552,1589,1741,1753,1796,1864,1876,1923,1997,2058,2064,2067,2176,2218,2349,2398,2467,2473,2529,2590,2618,2624,2627,2630,2708,2720,2723,2733,2750,2804,2867,2928,3004,3023,3055,3111,3293,3425,3449,3517,3591,3627,3732,3738,3849,3858,3885,3903,3912,3930,3944,3956,4018,4126,4135,4153,4183,4286,4342,4472,4625,4711,4769,4772,4815,4888,4932,5007,5032,5041,5081,5087,5102,5170,5176,5260,5269,5293,5324,5351,5470,5726,5784,5787,5819,5912,6034,6048,6053,6108,6120,6161,6222,6263,6493,6571,6629,6643,6793,6799,6832,6838,6870,6892,7004,7033,7116,7128,7198,7321,7336,7345,7348,7351,7390,7416,7474,7482,7501,7539,7650,7659,7683,7717,7752,7780,7783,7793,7816,7861,7933,7942,7945,8011,8128,8185,8210,8308,8404,8470,8531,8540,8543,8699,8729,8773,8776,8841,8847,8968,9029,9041,9220,9232,9330,9384,9510,9516,9590,9602,9605,9619,9740,9763,9874,9891,9897,9903,9909,9935,9941,9974,10029,10064,10256,10334,10484,10548,10635,10681,10690,10762,10860,10881,10887,10905,11026,11101,11115,11127,11255,11312,11355,11414,11434,11505,11528,11549,11558,11574,11682,11710,11856,11908,11970,12104,12118,12259,12265,12373,12392,12435,12469,12479,12499,12567,12734,12737,12839,12913,12936,12965,13024,13070,13082,13176,13213,13240,13368,13389,13419,13464,13494,13616,13646,13684,13715,13724,13816,13921,13987,14007,14034,14064,14067,14101,14131,14248,14297,14394,14397,14411,14427,14571,14649,14725,15057,15132,15146,15207,15234,15263,15270,15285,15392,15419,15608,15617,15628,15680,15683,15789,15868,16154,16157,16163,16178,16219,16259,16309,16368,16371,16407,16442,16566,16584,16649,16697,16725,16728,16752,16782,16890,17104,17192,17230,17277,17280,17413,17445,17542,17545,17570,17602,17647,17768,17810,17836,17854,17862,17870,17921,17924,17954,18003,18167,18294,18312,18318,18321,18330,18336,18342,18351,18362,18500,18535,18549,18622,18672,18754,18775,18816,18896,18902,18931,18951,18969,19004,19019,19022,19036,19056,19065,19100,19139,19172,19240,19325,19394,19424,19456,19479,19542,19636,19704,19710,19770,19862,19923,19935,19972,19993,20081,20225,20255,20288,20291,20431,20554,20628,20640,20690,20949,20985,21012,21015,21047,21167,21179,21287,21313,21463,21587,21606,21659,21690,21770,21813,21853,21894,21897,21935,22025,22042,22120,22166,22199,22229,22306,22344,22394,22400,22475,22835,22872,22875,22940,23033,23119,23157,23180,23207,23304,23313,23401,23466,23472,23523,23577,23634,23911,23916,23919,23976,24003,24098,24213,24256,24266,24301,24359,24391,24433,24448,24460,24493,24585,24708,24759,24767,24811,25194,25365,25371,25419,25433,25496,25793,25924,26023,26032,26077,26086,26205,26253,26287,26342,26375,26487,26561,26643,26652,26778,26832,26874,26957,26975,27059,27122,27156,27248,27254,27257,27266,27333,27471,27529,27656,27671,27685,27762,27781,27799,27842,27851,27881,27916,27998,28029,28180,28206,28400,28700,28710,28732,28823,28830,28853,28950,29440,29490,29500,29510,29763,29772,29827,29930,29996,30004,30034,30040,30238,30302,30393,30470,30478,30606,30651,30804,30880,30885,31003,31051,31135,31214,31348,31356,31431,31485,31494,31580,31601,31604,31700,31903,31974,32003,32213,32264,32292,32326,32337,32390,32454,32495,32509,32575,32673,32752,32803,33083,33236,33247,33255,33378,33489,33498,33556,33611,33636,33701,34106,34109,34161,34180,34286,34382,34385,34413,34526,34529,34621,34640,34676,34708,34717,34731,34850,35070,35129,35162,35204,35218,35350,35529,35568,35574,35588,35616,35645,35662,35759,35798,35807,35867,35881,35902,35940,35998,36110,36318,36321,36330,36351,36359,36505,36517,36532,36546,36562,36629,36879,37074,37131,37253,37282,37301,37333,37485,37497,37512,37556,37643,37648,37670,37730,37800,37890,37908,38042,38142,38194,38236,38286,38295,38298,38320,38382,38394,38432,38447,38656,38684,38704,38731,39009,39021,39084,39098,39154,39157,39190,39199,39249,39285,39294,39317,39344,39392,39395,39552,39596,39714,39729,39734,39762,39893,39947,39972,39997,40005,40044,40092,40101,40120,40413,40581,40630";
public TestDynamicInList(){
conn = connection();
conn.setAutoCommit(false);
}

protected void test() throws Exception {
testFunction();
testFE();
closeConn();
}

private void testFunction() throws SQLException{
System.out.println(" >>>>>>>>>>> Function Test <<<<<<<<<<<<<<<<< ");

String sql = "select object_id from test where object_id in (select /*+ cardinality(t 1)*/ * from table(cast (in_list(:x) as string_type)) t where rownum >= 0)";
PreparedStatement ps = null;
ResultSet rs = null;
long startTime = System.currentTimeMillis();
Hashtable<String,String> map = new Hashtable<String,String>();
try {
ps = conn.prepareStatement(sql);
ps.setString(1,data );
rs = (ResultSet)ps.executeQuery();
String id="";
while(rs.next()){
id = rs.getString(1);
map.put(id, id);
}
System.out.println(" # : "+map.size()+" | Function >>> : Time taken : " + (System.currentTimeMillis() - startTime)+ " ms");

} catch (Exception e) {
e.printStackTrace();
}finally{
if(rs != null){
rs.close();
}
if(ps != null){
ps.close();
}
}
}

private void testFE() throws SQLException {
System.out.println(" >>>>>>>>>>> Java Test <<<<<<<<<<<<<<<<< ");
Vector<String> vect = new Vector<String>();
vect.addAll(Arrays.asList(data.split(",")));

String sql = "select object_id from test where object_id in ([IDS])";
PreparedStatement ps = null;
ResultSet rset = null;
long startTime = System.currentTimeMillis();
Hashtable<String,String> map = new Hashtable<String,String>();
String id="";
try {
int i = 0;
for (Batch batch : Batch.get(vect,100, true)) {
i++;
System.out.println("Executed query : "+i+" times.");
ps = conn.prepareStatement(sql.replaceFirst("\\[IDS\\]", batch.getBindVarString()));
Object[] args = batch.getBindVars().toArray();
Batch.setArguments(ps, args);
rset = ps.executeQuery();
while(rset.next()){
id = rset.getString(1);
map.put(id, id);
}
}
} catch (Exception e) {
e.printStackTrace();
}finally{
if(rset!= null){
rset.close();
}
if(ps != null){
ps.close();
}
}

System.out.println(" # : "+map.size()+" | Batch/Java >>> : Time taken : " + (System.currentTimeMillis() - startTime)+ " ms");
}

/**
* @param args
* @throws Exception
*/
public static void main(String[] args) throws Exception {
TestDynamicInList l = new TestDynamicInList();
l.test();
}

private void connection(){
// Get the connection....
}

private void closeConn(){
if (conn != null) {
conn.close();
}
}
}


Tom Kyte
July 15, 2009 - 4:20 pm UTC

run it about 100 times please.

and through out the first (or even first N) observations. I think you

a) logon
b) run database way
c) run your "java" way

and your java way has had all of the classes loaded by the database way and you are not measuring anything realistic.

...
Sorry, I don't have access to get tkprofs. Please execuse me for this. I know
this is insufficient information.
....

get em


.. (I have presented only the necessary code
here...it won't compile).
.....


well, that would be a complete waste of my time - why would you give me something that we cannot run?!?!?!?!

How about..... You do it. The way I do it... And post the findings in a manner identical to the way I do - with tkprofs, and so on.

Java beats the function technique

A reader, July 15, 2009 - 4:51 pm UTC

Thanks Tom.

Can you suggest the right way to compare these two ?


Tom Kyte
July 15, 2009 - 4:57 pm UTC

I did???

use sql trace so we can see the tkprofs

run it, but ignore the first (typically you ignore the first COUPLE and the last COUPLE of observations)

eg:

loop 5 times
call database function
call java function

start timer
loop 100 times
call database function
stop timer (do NOT time inside the routine that is called, time the entire loop)


start timer
loop 100 times
call java function
stop timer (do NOT time inside the routine that is called, time the entire loop)

print results.

Pipelined functions And APEX

A reader, January 21, 2010 - 2:28 am UTC

Hi Tom,
HOpe this doesn't classify as a new question.

I have written a pipelined function that takes a delimited string and returns the strings themselves as rows. Initially I did this using a SQL query but then changed it to your example above.

Now I use this function in the conditions of APEX pages and fields and I keep hitting a 404 error. Since you use APEX a lot, I thought I would ask you too, if you were aware of any problem that could arise from using a pipelined function this way?

Brief background as to why I'm doing the above. I'm using custom authentication using APEX user groups and users. When a user logs in, I have an application item populated with all the groups they belong to and I have to check against this item to ensure that they are allowed functioanlity on the application.

I have tried the APEX forum but haven't had any response back yet. So thought I'd ask you. HOpe this is ok.

Thank you,
chandini
Tom Kyte
January 21, 2010 - 8:32 am UTC

... if you were aware of any problem that could arise from using a pipelined
function this way?
...

nope. not offhand.


you'll get the 404 not found when an error occurs, have you reviewed any of the error logs? maybe you have a bug in your code that is causing an error...

Update for above question

A reader, January 21, 2010 - 6:06 am UTC

Hi tom,
I have just found that the pipelined funtion was actually causing an error ORA-6548 and needed an exception handler for the NO_DATA_NEEDED exception.

Have you come across the above exception?

thanks,
Chandini
Tom Kyte
January 21, 2010 - 10:27 am UTC

It should not *need* an exception handler UNLESS the lack of one causes a logic bug in your application.

Normally, when you

select* from table(f(x))

you completely exhaust F(x), you run it till the return. but, what happens if you have code like:


create function f(x in number) return something PIPELINED
as
begin
   open resource (dbms_sql.open - for a cursor)
   open resource (packaged cursor, a global cursor)
   open resource (utl_file.fopen)
   etc....

   loop
      pipe row(...);
      exit when some condition
   end loop
   close all resources;
   return;
end;


Now, if you select * from table(f(x)) - and the client fetches everything, then all is OK - close all resources does what it needs.

But what if the client does something like:

open select * from table(f(x))
fetch a row
close

and there is more than one row? You have leaked some resources, you have left some global variable in an untenable state, you need a clean up.

So, you would code a when no_data_needed handler - and that'll get called when they close your cursor (the cursor calling you) before you are done. Consider:

ops$tkyte%ORA11GR1> create or replace function pipe_lined_function( x in number )
  2  return sys.odciNumberList
  3  PIPELINED
  4  is
  5  begin
  6      for i in 1 .. x
  7      loop
  8          pipe row(i);
  9      end loop;
 10      dbms_output.put_line( 'normal completion' );
 11      return;
 12  exception
 13      when no_data_needed then
 14          dbms_output.put_line( 'aborted' );
 15  end;
 16  /

Function created.

ops$tkyte%ORA11GR1> declare
  2      cursor c is select column_value from table(pipe_lined_function(2));
  3      n number;
  4  begin
  5      open c;
  6      fetch c into n;
  7      close c;
  8  end;
  9  /
aborted

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> select * from table(pipe_lined_function(2));

COLUMN_VALUE
------------
           1
           2

normal completion
ops$tkyte%ORA11GR1>



Now, that exception handler should be "optional", eg: if I leave it out:

ops$tkyte%ORA11GR1> create or replace function pipe_lined_function( x in number )
  2  return sys.odciNumberList
  3  PIPELINED
  4  is
  5  begin
  6      for i in 1 .. x
  7      loop
  8          pipe row(i);
  9      end loop;
 10      dbms_output.put_line( 'normal completion' );
 11      return;
 12  end;
 13  /

Function created.

ops$tkyte%ORA11GR1> declare
  2      cursor c is select column_value from table(pipe_lined_function(2));
  3      n number;
  4  begin
  5      open c;
  6      fetch c into n;
  7      close c;
  8  end;
  9  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> select * from table(pipe_lined_function(2));

COLUMN_VALUE
------------
           1
           2

normal completion
ops$tkyte%ORA11GR1>


Nothing bad happens, so I must presume that your error happened because of a side effect of your routine, not because you didn't catch no_data_needed. That is, you opened some resource in your pipelined function and when the client did not fetch all of the data - the fact you opened that resource and did not close it - caused a bug in your routine...

Followup

A reader, January 25, 2010 - 1:48 am UTC

Hi tom,
This is a followup to the query above.

I was using this function as part of an exists condition within APEX. WHich is what was raising the no_data_needed exception. It makes sense when you think about it I guess. I just never came across this exception before.

Thank you for your explanation.

Ta,
chandini
Tom Kyte
January 29, 2010 - 8:14 am UTC

right, but the only time it would become a problem is if you had cleanup that needed to be done - the exception didn't cause the error, the fact that your program unit didn't finish was the problem - and the exception was the way to handle it correctly.

sort of like this, neither function called is ever exhausted - only the first one fails simply because it has open a resource that cannot be opened again until closed - it is not that no_more_data is an error, rather that your code has a bug you fixed by using no_more_data...

ops$tkyte%ORA11GR2> create or replace package my_pkg
  2  as
  3          cursor c1 is select * from dual;
  4          cursor c2 is select * from dual;
  5  end;
  6  /

Package created.

ops$tkyte%ORA11GR2>
ops$tkyte%ORA11GR2> create or replace function foo1 return sys.odciNumberList pipelined
  2  is
  3  begin
  4          open my_pkg.c1;
  5          for i in 1 .. 1000
  6          loop
  7                  pipe row(i);
  8          end loop;
  9          close my_pkg.c1;
 10          dbms_output.put_line( 'normal completion' );
 11  end;
 12  /

Function created.

ops$tkyte%ORA11GR2>
ops$tkyte%ORA11GR2> create or replace function foo2 return sys.odciNumberList pipelined
  2  is
  3  begin
  4          open my_pkg.c2;
  5          for i in 1 .. 1000
  6          loop
  7                  pipe row(i);
  8          end loop;
  9          close my_pkg.c2;
 10          dbms_output.put_line( 'normal completion' );
 11  exception
 12          when no_data_needed
 13          then
 14                  close my_pkg.c2;
 15                  dbms_output.put_line( 'aborted' );
 16  end;
 17  /

Function created.

ops$tkyte%ORA11GR2>
ops$tkyte%ORA11GR2> select * from dual where exists (select null from table(foo1) where column_value = 1 );

D
-
X

ops$tkyte%ORA11GR2> select * from dual where exists (select null from table(foo2) where column_value = 1 );

D
-
X

aborted
ops$tkyte%ORA11GR2>
ops$tkyte%ORA11GR2> select * from dual where exists (select null from table(foo1) where column_value = 1 );
select * from dual where exists (select null from table(foo1) where column_value = 1 )
                                                        *
ERROR at line 1:
ORA-06511: PL/SQL: cursor already open
ORA-06512: at "OPS$TKYTE.MY_PKG", line 3
ORA-06512: at "OPS$TKYTE.FOO1", line 4


ops$tkyte%ORA11GR2> select * from dual where exists (select null from table(foo2) where column_value = 1 );

D
-
X

aborted
ops$tkyte%ORA11GR2>

varying elements in IN list

Jay Faux, April 19, 2010 - 2:27 pm UTC

Hi Tom;

This construct is very useful.
I have a question regarding why this sequnce works with your generic code:

select * from all_users
where user_id in ( select *
from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as mytableType ) from dual ) )

/

However, if I introduce a decode it fails with an 'more than one valuse in subquery' error:

select * from all_users
where user_id in ( DECODE (:rcode, '99', (user_id),
( select *
from THE ( select cast( str2tbl( '1, 3, 5, 7, 99' ) as mytableType ) from dual ) )
) )
/

It works for rcode 99 but not for any other value!!!

Thanks,
Jay
Tom Kyte
April 19, 2010 - 3:05 pm UTC

I'm not even sure what to make of the second query.


decode( ?, '99', USER_ID, <set> )


if ? = 99
then
return user_id
else
return a set?


I'm not sure what you are trying to do - decode doesn't work with sets, I would expect this to fail with ora-1427

in list

jay, April 19, 2010 - 11:02 pm UTC

Basically I want to return all from the 'all_users' table if I bind the rcode with '99'.
But only return user_ids [1, 3, 5, 7, 99] for any other rcode value.

It works if I pass the '99' - all rows from the 'all_users' table are returned.
For any other value, I get a 'more than one value in subquery' error.

Hope this is clear ....

thanks,
jay
Tom Kyte
April 20, 2010 - 8:11 am UTC

you want two queries then.


you want either:

<space left intentionally blank>


or

where user_id in ( select ... from table(:bind) )


since they will result in two very different plans.


Or, you can:

where user_id in (select .... )
or :rcode = '99';


in lists

jay, April 20, 2010 - 10:10 am UTC

Ok.
I already have two select statements with an if..then..else sequence to determine which to run but I was hoping to streamline the procedure by add the decode in the where clause.

Looks like it won't work .. thanks for you help.

Jay
Tom Kyte
April 20, 2010 - 10:50 am UTC

you could use a single sql statment - the problem is you WANT two for the different plans.


You could go with:

select * from t where :rcode = '99'
union all
select * form t where :rcode is null and user_id in (select .... );

that would be a single query that gives you an optimal plan for each path - only one of them would be executed at runtime - once we evaluate the :rcode bit.

clob_in_list

Sujith, June 01, 2010 - 6:18 pm UTC

Hi Tom,

I have been using your in_list funtion for years and in one area, the requirement changed from being a 1000 character input to a 11K + character string. This also is being passed from a web app. We were managed to treat this as a clob and as a result, I had to modify this function to handle the clob. I gave it a try, but doesn't seems to
getting the results back, obviously I have missed something here. Hope you can help or, suggest a completely new approach.

create or replace type TableTypeForClobTest as table
of varchar2 (4000);

create or replace function clob_in_list(p_string in clob)
return TableTypeForClobTest as
l_string clob default p_string || ';';
new_substr varchar2(4000);
l_data TableTypeForClobTest := TableTypeForClobTest();
n number;
v_substr_amount number;
v_amount NUMBER;
begin
loop
exit when l_string is null;
n := dbms_lob.instr(l_string, ';');
l_data.extend;
v_amount := dbms_lob.getlength(l_string);
v_substr_amount := n - 1;
dbms_lob.read(l_string, v_substr_amount, 1, new_substr);
l_data(l_data.count) := ltrim(rtrim(new_substr));
dbms_lob.read(l_string, v_amount, n + 1, l_string);
end loop;
return l_data;
end;
/

This doesn't seems to produce the outputs. I tested with a string like 'TX;Houston;Pearland'.

Thanks for all your help.

P.S. I encounted an error where it was cutting off the string at 8191 characters when using dbms_lob.substr, so instead changed it to use dbms_lob.read.

Sujith
Tom Kyte
June 08, 2010 - 9:31 am UTC

ops$tkyte%ORA10GR2> create or replace
  2  function in_list( p_string in clob ) return sys.odciVarchar2List
  3  pipelined
  4  as
  5      l_string        long default p_string || ';';
  6      n               number;
  7  begin
  8    loop
  9        exit when l_string is null;
 10        n := instr( l_string, ';' );
 11        pipe row( ltrim( rtrim( substr( l_string, 1, n-1 ) ) ) );
 12        l_string := substr( l_string, n+1 );
 13   end loop;
 14   return ;
 15  end;
 16  /

Function created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> variable x varchar2(2000)
ops$tkyte%ORA10GR2> exec :x := 'TX;Houston;Pearland';

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> select * from table( in_list(:x) );

COLUMN_VALUE
-------------------------------------------------------------------------------
TX
Houston
Pearland

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> declare
  2      l_data clob := '0';
  3  begin
  4      for i in 1..3000
  5      loop
  6          l_data := l_data || ';' || i;
  7      end loop;
  8      dbms_output.put_line( length( l_data ) );
  9
 10      for x in (select count(*) cnt,
 11                       min(to_number(column_value)) min,
 12                       max(to_number(column_value)) max
 13                  from table(in_list(l_data)) )
 14      loop
 15          dbms_output.put_line( x.cnt || ', ' || x.min || ', ' || x.max );
 16      end loop;
 17  end;
 18  /
13894
3001, 0, 3000

PL/SQL procedure successfully completed.

Built-in varchar2 datatype in the context of a collection definition

Mihail Bratu, June 11, 2010 - 5:28 am UTC

Hello Tom,

I found the following behavior for the collections of varchar2 type:
Let's create the table EMP_CHAR with the columns of varchar2 type based on CHAR instead of BYTE,

create table EMP_CHAR
(EMPNO NUMBER(4,0)
,ENAME VARCHAR2(10 CHAR)
,JOB VARCHAR2(9 CHAR)
,MGR NUMBER(4,0)
,HIREDATE DATE
,SAL NUMBER(7,2)
,COMM NUMBER(7,2)
,DEPTNO NUMBER(2,0)
)
/
insert into EMP_CHAR
select * from scott.EMP;

Now we create a collection type of a type, varchar2(10 char), that seems to take over the values from ename column.

create or replace type list_varchar10 as table of varchar2(10 char)
/
column enames format a140

The execution of the query below produces the ORA-22814 error.

select deptno,cast(collect(ename) as list_varchar10) enames
from EMP_CHAR
group by deptno
/
select deptno,cast(collect(ename) as list_varchar10) enames
*
ERROR at line 1:
ORA-22814: attribute or element value is larger than specified in type


Let's resume the test case above in two situations changing the collection type!
First:

create or replace type list_varchar40 as table of varchar2(40 byte)
/
select deptno,cast(collect(ename) as list_varchar40) enames
from EMP_CHAR
group by deptno
/
DEPTNO ENAMES
---------- --------------------------------------------------------------------------------------------------------------------------------------------
10 LIST_VARCHAR40('CLARK', 'KING', 'MILLER')
20 LIST_VARCHAR40('SMITH', 'FORD', 'ADAMS', 'SCOTT', 'JONES')
30 LIST_VARCHAR40('ALLEN', 'BLAKE', 'MARTIN', 'TURNER', 'JAMES', 'WARD')

Second:

drop type list_varchar10
/
create or replace type varchar10 as object (v10 varchar2(10 char))
/
create or replace type list_varchar10 as table of varchar10
/
select deptno,cast(collect(varchar10(ename)) as list_varchar10) enames
from EMP_CHAR
group by deptno
/
DEPTNO ENAMES(V10)
---------- --------------------------------------------------------------------------------------------------------------------------------------------
10 LIST_VARCHAR10(VARCHAR10('CLARK'), VARCHAR10('KING'), VARCHAR10('MILLER'))
20 LIST_VARCHAR10(VARCHAR10('SMITH'), VARCHAR10('FORD'), VARCHAR10('ADAMS'), VARCHAR10('SCOTT'), VARCHAR10('JONES'))
30 LIST_VARCHAR10(VARCHAR10('ALLEN'), VARCHAR10('BLAKE'), VARCHAR10('MARTIN'), VARCHAR10('TURNER'), VARCHAR10('JAMES'), VARCHAR10('WARD'))

Looks like the primary type varchar2, used in collection context, can't handle the definition based on char.
Am I missing something?


Tom Kyte
June 11, 2010 - 7:41 am UTC

ops$tkyte%ORA11GR2> create table t(x VARCHAR2(10 CHAR));

Table created.

ops$tkyte%ORA11GR2> create or replace type list_varchar10 as table of varchar2(10 char)
  2  /

Type created.

ops$tkyte%ORA11GR2> select cast(collect(x) as list_varchar10) enames from t;
select cast(collect(x) as list_varchar10) enames from t
            *
ERROR at line 1:
ORA-22814: attribute or element value is larger than specified in type


ops$tkyte%ORA11GR2> desc t
 Name                                     Null?    Type
 ---------------------------------------- -------- ----------------------------
 X                                                 VARCHAR2(10 CHAR)

ops$tkyte%ORA11GR2> desc list_varchar10
 list_varchar10 TABLE OF VARCHAR2(10 CHAR)


Yes, I'd say that is a bug, you need a multi-byte database to see it.

Do you have access to metalink, can you file this smaller test case? if not, let me know

Mihail Bratu, June 11, 2010 - 7:54 am UTC

Thank you very much for your quickly response and for this site too!

I haven’t an easy access to metalink so I base on you, like always.

Dynamic IN lists

Ananth, June 26, 2010 - 5:29 am UTC

Hi Tom,

we dont have privileges to create Objects or Types in database. we can only create types/collections in our anonymous blocks of plsql.

Scenario:
-----------
OS used: Unix
DB: Oracle 10g R2

from shellscript we call sqlplus.
we get input data from files (say input.txt), somehow we managed to format the input data to readable format. Remember the data in input file vary between 100 to 10000.

Approach1:
In this approach, we loop each record in file and for every record we call the sqlplus and execute anonymous block of code (querying a table or executing a stored procedure dynamically etc).

as this approach connects and disconnects to DB everytime, also it is time consuming. so we thought of goin with another approach

Approach 2:
we create temporary files of (say 3000) records and call teh sqlplus for every temporary file.
in the sqlplus we created a plsql table,

declare
type t_tbl is table of sometable.col1;
tb_tbl t_tbl;
begin
tb_tbl := t_tbl(cat ${tmpfile});
....... <processing on tb_tbl>;
..........
end;

instead of calling the sqlplus for every record in file, we now call sqlplus for every 3000 records.
if we try to increase the count from 3000 to 4000 or more, we get error (PLS-00123: program too large)

can you suggest any other better approach than this (keeping in mind that we dont have privileges to create objects/types/global temporary tables ib DB).

ThanX in advance

~Ananth
Tom Kyte
July 06, 2010 - 11:01 am UTC

... we dont have privileges to create Objects or Types in database....

that is ok, you have

sys.odcinumberList
sys.odcivarchar2List

you can use. They exist.


but, you do not even need them nowadays

http://asktom.oracle.com/Misc/varying-in-lists.html

Varying "IN" List

Ananth, July 09, 2010 - 1:06 am UTC

Hi tom,

Thanx for the response,

as per the link suggested above, when i tried to use bind variables, i get SP2-0027; Input too long error..

is there any other alternative to avoid this eror..

Regards
Ananth
Tom Kyte
July 09, 2010 - 8:24 am UTC

how long is your input, if longer than 4000 bytes - my suggestion would definitely be:


create global temporary table gtt ( data ... primary key ) on commit delete rows;


and in your program, array insert (bulk insert) the values in there and then

select * from t where x in (select * from gtt);


If you have a string of more than 4000 characters, you have hundreds of things in your in list, that will equate to hundreds of OR's in the sql statment (in (a,b,c) is really x=a or x=b or x=c) and you want (you really really want) to use in ( subquery ) instead.

Varying IN List

A reader, August 22, 2010 - 2:55 pm UTC

Hi Tom,

i tried implementing the varying inlists using
1. OR clauses, i.e where ( x=a) or (x=b) or (x=c)
2. UNION ALL clauses. i.e where x=a union all select.. x=b ..

it seemed to be a solution.
however for around 10 to 15, both the above said approaches worked fine, but for 10000, it took lot of time to execute it. right now i dont have the stats.

sometimes i get the errors related to shared memory.
because of that i really cannot opt this approach..

~Ananth

I LOVE U

Paulo Diogo, August 24, 2011 - 8:06 am UTC

YOU ARE THE BEST!

Replace IN keyword with INSTR function

Howard Wan, September 13, 2011 - 4:15 pm UTC

SELECT count(fksrev) into nCount
FROM SREVSECT
WHERE INSTR(pSectNos || ',', sectno || ',') > 0

/* where pSectNos is as in 'abc, xyz, 012' */

Tom's solution works but it is very very slow when there are a lot of data in the table. Using INSTR() is much faster.
Tom Kyte
September 14, 2011 - 4:12 pm UTC

prove it.

If the plan generated is correct - I can get records out of a 10 kabillion row table in milliseconds using my approach.

And what would yours take?


If you plan on using an index to retrieve rows - I'm sorry but your approach is "not good"

and even if you plan on full scanning - i would envision an in with a list of values to be compared - rather than applying a function to every row over and over - to be superior.


In current releases, I prefer this approach (although the same would hold true for the pipelined function)


for example:

big_table%ORA11GR2> variable txt varchar2(100)
big_table%ORA11GR2> exec :txt := 'BIG_TABLE,UTIL,A,B';

PL/SQL procedure successfully completed.

big_table%ORA11GR2> 
big_table%ORA11GR2> with data
  2  as
  3  (
  4  select
  5    trim( substr (txt,
  6          instr (txt, ',', 1, level  ) + 1,
  7          instr (txt, ',', 1, level+1)
  8             - instr (txt, ',', 1, level) -1 ) )
  9      as token
 10     from (select ','||:txt||',' txt
 11             from dual)
 12   connect by level <=
 13      length(:txt)-length(replace(:txt,',',''))+1
 14  )
 15  select * from data;

TOKEN
----------------------------------------------------------------------------------------------------------------------------------
BIG_TABLE
UTIL
A
B

big_table%ORA11GR2> 
big_table%ORA11GR2> select count(*) from big_table;

  COUNT(*)
----------
   1000000

big_table%ORA11GR2> 
big_table%ORA11GR2> set timing on
big_table%ORA11GR2> set autotrace traceonly
big_table%ORA11GR2> with data
  2  as
  3  (
  4  select
  5    trim( substr (txt,
  6          instr (txt, ',', 1, level  ) + 1,
  7          instr (txt, ',', 1, level+1)
  8             - instr (txt, ',', 1, level) -1 ) )
  9      as token
 10     from (select ','||:txt||',' txt
 11             from dual)
 12   connect by level <=
 13      length(:txt)-length(replace(:txt,',',''))+1
 14  )
 15  select *
 16    from big_table
 17   where owner in (select * from data);

52 rows selected.

Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
Plan hash value: 3400944537

--------------------------------------------------------------------------------------------------
| Id  | Operation                         | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                  |              | 10000 |  1152K|   181   (1)| 00:00:03 |
|   1 |  NESTED LOOPS                     |              |       |       |            |          |
|   2 |   NESTED LOOPS                    |              | 10000 |  1152K|   181   (1)| 00:00:03 |
|   3 |    VIEW                           | VW_NSO_1     |     1 |    19 |     2   (0)| 00:00:01 |
|   4 |     HASH UNIQUE                   |              |     1 |    19 |            |          |
|   5 |      VIEW                         |              |     1 |    19 |     2   (0)| 00:00:01 |
|*  6 |       CONNECT BY WITHOUT FILTERING|              |       |       |            |          |
|   7 |        FAST DUAL                  |              |     1 |       |     2   (0)| 00:00:01 |
|*  8 |    INDEX RANGE SCAN               | BT_OWNER_IDX |  4000 |       |    68   (0)| 00:00:01 |
|   9 |   TABLE ACCESS BY INDEX ROWID     | BIG_TABLE    | 10000 |   966K|   178   (0)| 00:00:03 |
--------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   6 - filter(LEVEL<=LENGTH(:TXT)-LENGTH(REPLACE(:TXT,',',''))+1)
   8 - access("OWNER"="TOKEN")


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         68  consistent gets
          0  physical reads
          0  redo size
       2585  bytes sent via SQL*Net to client
        453  bytes received via SQL*Net from client
          5  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
         52  rows processed

big_table%ORA11GR2> 
big_table%ORA11GR2> SELECT *
  2  FROM big_table
  3  WHERE INSTR(:txt || ',', owner || ',') > 0
  4  /

52 rows selected.

Elapsed: 00:00:00.34

Execution Plan
----------------------------------------------------------
Plan hash value: 3993303771

-------------------------------------------------------------------------------
| Id  | Operation         | Name      | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |           | 50000 |  4833K|  3955   (1)| 00:00:48 |
|*  1 |  TABLE ACCESS FULL| BIG_TABLE | 50000 |  4833K|  3955   (1)| 00:00:48 |
-------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(INSTR(:TXT||',',"OWNER"||',')>0)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
      14507  consistent gets
      14500  physical reads
          0  redo size
       5832  bytes sent via SQL*Net to client
        453  bytes received via SQL*Net from client
          5  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         52  rows processed

big_table%ORA11GR2> set autotrace off




Performance while using inlist

Sarma, September 15, 2011 - 9:59 am UTC

Hi Tom,

I see drastic performance difference between following two queries when combined with high buffer gets sql.

SELECT *
FROM TABLE(CAST (
GETINLIST.GETNUMBERLIST_CLOB (:P_PLAN_INT_ACCTS)
AS NUMBERTABLETYPE
));

--this query is running very fast combined i with main query.
SELECT *
FROM THE (SELECT CAST (
GETINLIST.GETNUMBERLIST_CLOB (:P_PLAN_INT_ACCTS)
AS NUMBERTABLETYPE
) FROM DUAL);


Tom Kyte
September 16, 2011 - 1:15 pm UTC

give a full example, I have no idea what you mean. you'll need to create the types and set up the entire example.

you know, just like I do every single time.

Performance using inlist

Sarma, October 05, 2011 - 12:32 pm UTC

Hi Tom,

Performance difference is because of scalar subquery cahing.

Thanks
Tom Kyte
October 05, 2011 - 12:47 pm UTC

I'll reiterate:

give a FULL EXAMPLE


since either of the above queries are basically the same.

No example
No clue what you mean
No idea how you are using this
No help to anyone else therefore...

Indexes not getting used

Neetesh, November 14, 2011 - 1:05 am UTC

Hi Tom,
I am using a pipe row based version of the function you provided above and read that even that can be used as good as your function. 


CREATE TABLE "USERSECURITY"
  (
    "USERID"         VARCHAR2(50 BYTE),
    "PARENTMEMBERS" VARCHAR2(4000 CHAR),
)


create or replace
function split
 (
     p_list varchar2,
     p_del varchar2 := '|'
 ) return split_tbl pipelined
 is
     l_idx    pls_integer;
     l_list    varchar2(32767);
     l_value    varchar2(32767);
 begin
     select parentmembers into l_list from usersecurity where userid=p_list;
     loop
         l_idx :=instr(l_list,p_del);
         if l_idx > 0 
         then
             PIPE ROW ( substr(l_list,1,l_idx-1) );
             l_list:= substr(l_list,l_idx+length(p_del));
         else
             PIPE ROW (l_list);
             exit;
         end if;
     end loop;
     return;
 end split;


and I use the split function as 

select level0 from rpt_costcentres where rptgen4 in (select * from table(split('xyz')))
union
select level0 from rpt_costcentres where rptgen5 in (select * from table(split('xyz')))union
select level0 from rpt_costcentres where rptgen6 in (select * from table(split('xyz')))
union
select level0 from rpt_costcentres where rptgen7 in (select * from table(split('xyz')))
 

CREATE TABLE "RPT_COSTCENTRES"
  (
    "RPTGEN1"       CHAR(11 BYTE),
    "RPTGEN2"       VARCHAR2(200 BYTE),
    "RPTGEN4"       VARCHAR2(200 BYTE),
    "RPTGEN5"       VARCHAR2(200 BYTE),
    "RPTGEN6"       VARCHAR2(200 BYTE),
    "RPTGEN7"       VARCHAR2(200 BYTE),
     "LEVEL0"        VARCHAR2(200 BYTE),
  )

the indexes on the table are - 
create index cc_index1 on rpt_costcentres(rptgen4, level0) compress 1 ; 
create index cc_index2 on rpt_costcentres(rptgen5, level0) compress 1 ;
create index cc_index3 on rpt_costcentres(rptgen6, level0) compress 1 ; 
create index cc_index4 on rpt_costcentres(rptgen7, level0) compress 1 ;


and now cost of the query increases like anything ?

What is the mistake that I am doing or should i just ignore the query plan - 

 OPERATION   OBJECT_NAME   OPTIONS   COST  
 

  SELECT STATEMENT   1421161  
      

  SORT  
      UNIQUE   1421161  
           

  UNION-ALL  
             
               
  HASH JOIN            215  
                     

  Access Predicates  
 
                         
  RPTGEN4=VALUE(KOKBF$)  
 
                     
  COLLECTION ITERATOR  
  SPLIT   PICKLER FETCH      
                     
  INDEX  
  CC_INDEX1   FAST FULL SCAN   48  
                

  HASH JOIN            105  
                

  HASH JOIN            96  
                     

  Access Predicates  
 
                          

  RPTGEN6=VALUE(KOKBF$)  
 
                     

  COLLECTION ITERATOR    SPLIT   PICKLER FETCH      
                     

  INDEX  
  CC_INDEX3   FAST FULL SCAN   49  
                

  HASH JOIN            91  


Tom Kyte
November 15, 2011 - 8:25 am UTC

who cares about the cost.

how does it perform?

what the HECK does it look like? Give a complete example - just like I always do - please.

and make it *readable*

Indexes not getting Used continued

Neetesh, November 14, 2011 - 1:19 am UTC

Just as an update the split function needs to be called as
split('xyz|abc|123')

GTT and in-list pairs

Ahmed, April 25, 2012 - 10:50 am UTC

Hi Tom,

I have the following schema:

table Relation ( id varchar2(15) not null, primary varchar2(15), secondary varchar2(15), relation_type varchar2(15))
primary, secondary and relation_type are all secondary links to other objects in the database.
now I have a list of secondary and relation_type pairs that I gathered from a number of objects loaded in my session and I want to query the Relation table for a list of primary given the list of pairs (secondary, relation_type).

I cannot use an In-list here because I will get many false positives. so I have to create a temporary table that holds
secondary, relation_type pairs and then write my query as follows:

select t1.primary from Relation t1, Gtt t2 WHERE t1.secondary = t2.secondary AND t1.relation_type= t2.relation_type.

This query is slow in Oracle and I wonder if there is any better way to achieve this without the need to use GTT or PL/SQL.

many thanks.
Tom Kyte
April 25, 2012 - 2:49 pm UTC

this query would not be "slow"

please define slow
supply a tkprof of this slowness (with actual cardinalities)
let us see a plan as well (with estimated cardinalities)

GTT and in-list pairs

Ahmed, April 27, 2012 - 5:30 am UTC

Thanks Tom.
I did not think it will be slow but some DBAs raised issues regarding this SQL which always appears among the stop 10 SQLs in the session in AWR report.

You have give me what I want so thanks for your time.

Why no plans in shared pool?

Rajeshwaran, Jeyabal, June 20, 2012 - 2:18 am UTC

Tom:

Can you please tell me why i don't see any entry in shared pool for /* QUERY_2 */ ?

rajesh@ORA10GR2> create or replace function foo
  2  (p_in varchar2)
  3  return number as
  4     l_count number;
  5  begin
  6     execute immediate ' alter session set cursor_sharing=force';
  7     execute immediate ' select /* QUERY_1 */ count(*) from t
  8     where username in ('||p_in||')' into l_count;
  9     execute immediate ' alter session set cursor_sharing=exact';
 10     return l_count;
 11  end;
 12  /

Function created.

Elapsed: 00:00:00.28
rajesh@ORA10GR2>
rajesh@ORA10GR2> create or replace function foo1
  2  (p_in varchar2)
  3  return number as
  4     l_count number;
  5  begin
  6  select /* QUERY_2 */ count(*)
  7  into l_count
  8  from t
  9  where username in ( select * from table
 10     ( select cast( in_list(p_in) as mytype )
 11     from dual ) );
 12  return l_count;
 13  end;
 14  /

Function created.

Elapsed: 00:00:00.09
rajesh@ORA10GR2>
rajesh@ORA10GR2> column sql_text format a30 trunc;
rajesh@ORA10GR2>
rajesh@ORA10GR2> exec dbms_output.put_line ( foo( ' ''SCOTT'',''SYS'', ''RAJESH'' ' ) );
3

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.01
rajesh@ORA10GR2> exec dbms_output.put_line ( foo( ' ''SCOTT'',''SYS'' ' ) );
2

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.01
rajesh@ORA10GR2>
rajesh@ORA10GR2> SELECT sql_text,sql_id,executions
  2  FROM v$sql
  3  where sql_text like ' select /* QUERY_1 */ count(*)%';

SQL_TEXT                       SQL_ID        EXECUTIONS
------------------------------ ------------- ----------
 select /* QUERY_1 */ count(*) 2hg039bhmd9bz          1
 select /* QUERY_1 */ count(*) 3276vzyd5bqw2          1

Elapsed: 00:00:00.03
rajesh@ORA10GR2>
rajesh@ORA10GR2> exec dbms_output.put_line ( foo1( q'|SCOTT,SYS,RAJESH|') );
3

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.03
rajesh@ORA10GR2> exec dbms_output.put_line ( foo1( q'|SCOTT,SYS|') );
2

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.01
rajesh@ORA10GR2>
rajesh@ORA10GR2> SELECT sql_text,sql_id,executions
  2  FROM v$sql
  3  where sql_text like 'select /* QUERY_2 */ count(*)%';

no rows selected

Elapsed: 00:00:01.03
rajesh@ORA10GR2>

Tom Kyte
June 21, 2012 - 7:25 am UTC

because plsql will normalize your queries and uppercase much of it and remove comments.

use /*+ QUERY_2 */ - make it look like a hint and it'll be preserved.

and then use


where lower(sql_text) like 'select%/*+%query_2%*/%';



IN_LIST as Procedure with OUT parameter

Narendra, February 14, 2013 - 11:33 am UTC

Hi Tom

I have procedure which has two OUT parameters, one of them is of mytableType type.

So, How can i use bellow select statement.

select * from some_table where some_column IN (select * from THE ( select cast( in_list as mytableType ) from dual ) a )

here , IN_LIST is a procedure which return mytableType as OUT parameter.

I am getting error when execute this select statement with procedure. Can you please help me on this with workaround?
Tom Kyte
February 14, 2013 - 11:56 am UTC

you cannot call a procedure from sql, you can only call a function that returns a single output and accepts only IN parameters.

You'll have to write a function that calls this procedure and invoke the function from SQL.


Use of your strtab function with AND query

Phil, April 11, 2013 - 8:42 am UTC

Hi Tom,
I've used your strtab function for a long time in conjunction with APEX as shuttle and checkbox items lend themselves very well to this.
I've got an SQL challenge that on first glance looks simple but it has got me stumped!

For sake of a simplified example I have two tables.
create table task(id number);
create table task_refs(task_id number, task_ref number);

insert into task values (1);
insert into task_refs values (1,1);
insert into task_refs values (1,2);
insert into task_refs values (1,3);
insert into task_refs values (1,4);

Now, if a user wants to perform a query on a dataset they use a shuttle to select items and choose a radio button for AND or OR operator.

The OR is fine as we use the strtab function as so:

select id from task where id in
(
select task_id from task_refs where task_ref in
(select column_value from TABLE(strtab(:P_SHUTTLE_ITEM)))
)

However, I am stuck on the AND clause using SQL alone.

I am sure this can be done using SQL. It would be fine to do this procedurally but I am keen to avoid this unless I really have to!

The SQL would have to be dynamically generated unless I can do this - example below:

select id from task
where id in (select task_id from task_refs where task_ref=123)
and id in (select task_id from task_refs where task_ref=456)
and id in (select task_id from task_refs where task_ref=789)
and id in (select task_id from task_refs where task_ref=474)
and id in (select task_id from task_refs where task_ref=873) -- and so on...

I am using 10gR2 and APEX 3.2.

Many thanks in advance, I'll happily swap out some procedural code for an SQL solution (if it is possible!)

Phil

Tom Kyte
April 22, 2013 - 2:54 pm UTC

ops$tkyte%ORA11GR2> variable x varchar2(20)
ops$tkyte%ORA11GR2> exec :x := '1,2,3,4'

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> with data
  2  as
  3  (select *
  4     from table(str2tbl(:x))
  5  )
  6  select id, count(distinct task_ref)
  7    from task, task_refs
  8   where task_ref in (select * from data)
  9   group by id
 10  having count(distinct task_ref) = (select count(*) from data)
 11  /

        ID COUNT(DISTINCTTASK_REF)
---------- -----------------------
         1                       4

ops$tkyte%ORA11GR2> exec :x := '1,2,3,4,5'

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR2> /

no rows selected

ops$tkyte%ORA11GR2> 

what if we dont use Pl/SQL and just sql ?

anwesh joshi, July 08, 2019 - 7:43 pm UTC

I don't have permission to create tables so i used "with" to create a temporary table and solved it for smaller case (I dont think it's a perfect bind but works good). Now I have issue with larger list where the parameter string is too large, how can I fix that?
Chris Saxon
July 09, 2019 - 2:18 pm UTC

What exactly is the issue you're hitting? Show us the SQL you're running and the error you get!

Performance using type table in select statement

indrajeet, October 20, 2020 - 2:16 pm UTC

Hi Tom,

I have written a SP to return customer info using cursor.
Input is list of customer info where i used type table.

following SP works and return result too, but the response time is huge 30 seconds.

if I execute simple select statement with hardcoded values
SELECT * FROM CUST WHERE CUST_ID IN ('111', '2321') response is fraction of second, but using type table in where in clause is very slow.

for Select output using type object, I tried both "where in ()" and also "join", but both are too slow.

Kindly help me to optimize it to have quick response?

--CREATED TYPE TABLE
create or replace type my_obj as object(item varchar2(20));
create or replace type STRING_TABLE as table of my_obj;

--SP TO RETURN CURSOR FOR CUST INFO INPUT LIST OF CUSTOMER
create or replace PROCEDURE GET_CUSTOMER_INFO
( 
  ACCOUNT_LIST IN STRING_TABLE,
  CURSOR_ACC_INFO OUT SYS_REFCURSOR
 )

AS
BEGIN

OPEN CURSOR_ACC_INFO FOR 

SELECT * 
    FROM CUST  
    WHERE CUST_ID IN (SELECT ITEM FROM  TABLE(ACCOUNT_LIST));

/*
SELECT * 
    FROM CUST,  TABLE(ACCOUNT_LIST)  
    WHERE CUST_ID = ITEM;
*/

END


Connor McDonald
October 21, 2020 - 1:21 am UTC

Adrian Billington has a nice writeup on how to set the cardinality for a table function which should help here

http://www.oracle-developer.net/display.php?id=427

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library