Thanks for the test case.
Ultimately, you generated the following PLSQL block
begin
EXECUTE IMMEDIATE
'SELECT id,
name,
type
FROM test_dy
WHERE (LOWER(name) LIKE LOWER(:3) OR LOWER(name) LIKE LOWER(:5) )
ORDER BY name asc
OFFSET 0 ROWS FETCH NEXT 50 ROWS ONLY'
BULK COLLECT INTO l_arId, l_arName, l_arType
USING '%Mark%', 'Will%';
end;
Notice that in the scope of that block, it has no idea what l_arId, l_arName, l_arType are. Even you *generated* this block inside the parent block, it doesn't mean it *knows* that what the parent block is.
Thus you need to let this generated block know what to do with those return values
SQL>
SQL> CREATE OR REPLACE TYPE typ_arrChar IS TABLE OF VARCHAR2(4000);
2 /
Type created.
SQL>
SQL> CREATE TABLE test_dy (id VARCHAR2(512 CHAR), name VARCHAR2(512 CHAR), type VARCHAR2(128), CONSTRAINT testdy_id_pk PRIMARY KEY(id));
Table created.
SQL> INSERT INTO test_dy VALUES('id1', 'Mark', 'Full-time');
1 row created.
SQL> INSERT INTO test_dy VALUES('id2', 'Will', 'Full-time');
1 row created.
SQL> INSERT INTO test_dy VALUES('id3', 'Joe', 'Part-time');
1 row created.
SQL>
SQL> CREATE OR REPLACE PROCEDURE testDy_prc
2 (
3 i_sql_1 IN VARCHAR2,
4 i_sql_2 IN VARCHAR2
5 )
6 AS
7 l_sql VARCHAR2(32767);
8 l_arId typ_arrChar := typ_arrChar();
9 l_arName typ_arrChar := typ_arrChar();
10 l_arType typ_arrChar := typ_arrChar();
11 BEGIN
12 l_sql := 'SELECT id,
13 name,
14 type
15 FROM test_dy
16 WHERE
17 (' || CHR(10)
18 || i_sql_1
19 || CHR(10) ||
20 ')
21 ORDER BY name asc
22 OFFSET 0 ROWS FETCH NEXT 50 ROWS ONLY
23 ';
24
25 EXECUTE IMMEDIATE
26 ' BEGIN
27 EXECUTE IMMEDIATE ''' || l_sql || '''
28 BULK COLLECT INTO :l_arId, :l_arName, :l_arType
29 USING ' || i_sql_2 ||';END;' using out l_arId, out l_arName, out l_arType;
30
31 IF (l_arName.COUNT>0) THEN
32 FOR i IN 1 .. l_arName.COUNT
33 LOOP
34 dbms_output.put_line('name: ' || l_arName(i));
35 END LOOP;
36 END IF;
37 END testDy_prc;
38 /
Procedure created.
SQL>
SQL> set serverout on
SQL> DECLARE
2 l_sql_1 VARCHAR2(32767);
3 l_sql_2 VARCHAR2(32767);
4 BEGIN
5 l_sql_1 := 'LOWER(name) LIKE LOWER(:3) OR LOWER(name) LIKE LOWER(:5)';
6 l_sql_2 := '''%Mark%'', ''Will%''';
7
8 testDy_prc
9 (
10 i_sql_1 => l_sql_1,
11 i_sql_2 => l_sql_2
12 );
13 END;
14 /
name: Mark
name: Will
PL/SQL procedure successfully completed.
SQL>
SQL>
SQL>