The AskTOM team is taking a break over the holiday season, so we're not taking questions or responding to comments. Please have a happy and safe festive season and as always, thanks for being a member of the AskTOM community.
Thanks for the question, Marek.
Asked: November 30, 2022 - 8:10 am UTC
Last updated: December 01, 2022 - 4:52 am UTC
Version: 19.17.0.1.0
Viewed 1000+ times
SQL> create or replace FUNCTION fmv_space_to_table(p_list IN VARCHAR2) 2 RETURN sys.odcivarchar2list 3 AS 4 l_string VARCHAR2(32767) := p_list || ' '; 5 l_comma_index PLS_INTEGER; 6 l_index PLS_INTEGER := 1; 7 l_tab sys.odcivarchar2list := sys.odcivarchar2list(); 8 BEGIN 9 LOOP 10 l_comma_index := INSTR(l_string, ' ', l_index); 11 EXIT 12 WHEN l_comma_index = 0; 13 l_tab.EXTEND; 14 l_tab(l_tab.COUNT) := TRIM(SUBSTR(l_string, 15 l_index, 16 l_comma_index - l_index 17 ) 18 ); 19 l_index := l_comma_index + 1; 20 END LOOP; 21 RETURN l_tab; 22 END fmv_space_to_table; 23 / Function created. SQL> SQL> SQL> select * from table( fmv_space_to_table( 'A2345 123456 7890 2344')); COLUMN_VALUE ---------------------------------------------------------------------------------------------------------------------------------- A2345 123456 7890 2344 4 rows selected. SQL> SQL> select * from table( fmv_space_to_table( 'A2345')); COLUMN_VALUE ---------------------------------------------------------------------------------------------------------------------------------- A2345 1 row selected. SQL> SQL> select * from emp 2 where ename in ( select * from table( fmv_space_to_table( 'A2345')) ); no rows selected SQL> SQL> select * from emp 2 where empno in ( select * from table( fmv_space_to_table( 'A2345')) ); where empno in ( select * from table( fmv_space_to_table( 'A2345')) ) * ERROR at line 2: ORA-01722: invalid number SQL> SQL> SQL> select * from emp 2 where empno in ( select * from table( fmv_space_to_table( A2345)) ); where empno in ( select * from table( fmv_space_to_table( A2345)) ) * ERROR at line 2: ORA-00904: "A2345": invalid identifier SQL> SQL>
Ray H, December 01, 2022 - 11:11 am UTC
SELECT REGEXP_SUBSTR('ABCD EFGH IJKL MNOP 1234 5678', '[^ ]+', 1, LEVEL) AS STRING_TO_TAB FROM DUAL CONNECT BY LEVEL <= REGEXP_COUNT('ABCD EFGH IJKL MNOP 1234 5678', ' ') + 1;
Check out more PL/SQL tutorials on our LiveSQL tool.
PL/SQL reference manual from the Oracle documentation library