Monday, 24 December 2012

Returning multiple values from function in oracle?

How to return table datatype from function in oracle?
There could be a situation where you want a function to return multiple values. Let's consider an example. Suppose you have a string with comma separated number str='1,2,3,4'. Now you want that function to separate these comma separated values and return you something like this.
1
2
3
4
It means you want your function to behave something like tables. So we will create a function that will return us a table. We will demonstrate you how this can be achieved.


SQL> create type t_row as object (a varchar2(10));
  2  /
Type created.

SQL> create type t_row_tab as table of t_row;
  2  /
Type created.

We will now create a function which will split the input string.

create or replace function get_number(pv_no_list in varchar2) return t_row_tab is
lv_no_list t_row_tab := t_row_tab();
begin

  for i in (SELECT distinct REGEXP_SUBSTR(pv_no_list, '[^,]+', 1, LEVEL) no_list FROM dual
  CONNECT BY REGEXP_SUBSTR(pv_no_list, '[^,]+', 1, LEVEL) IS NOT NULL)
  loop
  lv_no_list.extend;
  lv_no_list(lv_no_list.last) := t_row(i.no_list);
  end loop;
  
  return lv_no_list;

end get_number;

Once the function is in place we can use the table clause of sql statement to get the desired result. As desired we got multiple values returned from the function.

SQL> select * from table(get_number('1,2,3,4'));
A
----------
1
3
2
4

SQL>  select * from table(get_number('10,25,34,89,77'));
A
----------
89
77
10
25
34


So now our function is simply behaving like a table. There can be a situation where you want these comma separated values to be a part of "IN" clause. 

For example :

select * from dummy_table where dummy_column in ('1,2,3,4');

But the above query will not work as '1,2,3,4' is a string and not individual numbers. To solve this problem you can simply use following query.

select * from dummy_table where dummy_column in ( select * from table(get_number('1,2,3,4')) );

No comments:

Post a Comment

back to top