This is the next level question for how to pass object type as a parameter in oracle.
My question is in the same context a bit deeper with master-child nested level relationship, which is object with in the object. And I didn't find any way to call such procedure from PL-SQL.
Let's modify the example given in the above question as below :
Creating objects and types:
CREATE OR REPLACE TYPE domain_details_ot AS OBJECT
(
domain_name VARCHAR2(50),
domain_ip VARCHAR2(50)
);
CREATE OR REPLACE TYPE domain_details_nt AS TABLE OF domain_details_ot;
CREATE OR REPLACE TYPE CALLBACK_T AS OBJECT
(
url VARCHAR2(50),
uri_key NUMBER,
domains domain_details_nt
);
CREATE OR REPLACE TYPE callbck AS TABLE OF callback_t;
Create and Insert Statements for the requirement :
CREATE TABLE url_hdr
(url_hdr_id INT
, url VARCHAR2(100)
, url_key NUMBER
, CONSTRAINT url_hdr_pk PRIMARY KEY (url_hdr_id)
);
CREATE TABLE url_dtl
(url_dtl_id INT
, url_hdr_id INT
, domain_name VARCHAR2(500)
, domain_ip VARCHAR2(50)
, CONSTRAINT url_dtl_pk PRIMARY KEY (url_dtl_id)
, CONSTRAINT url_dtl_fk1 FOREIGN KEY (url_hdr_id) REFERENCES url_hdr(url_hdr_id)
);
INSERT INTO url_hdr VALUES (1, 'www.abc.com', 12345);
INSERT INTO url_hdr VALUES (2, 'www.xyz.com',23456);
INSERT INTO url_dtl VALUES (1, 1, 'abc.com', '0.0.0.0');
INSERT INTO url_dtl VALUES (2, 1, 'def.com', '0.0.0.1');
INSERT INTO url_dtl VALUES (3, 2, 'uvw.com', '0.0.0.2');
INSERT INTO url_dtl VALUES (4, 2, 'xyz.com', '0.0.0.3');
COMMIT;
SELECT uh.url, uh.url_key, ud.domain_name, ud.domain_ip
FROM url_hdr uh
,url_dtl ud
WHERE uh.url_hdr_id = ud.url_hdr_id
AND uh.url_hdr_id IN (1,2);
Procedure Sample Code :
CREATE OR REPLACE PROCEDURE get_callback_info(
pi_clbk IN callbck := callbck()
)
IS
BEGIN
FOR i IN 1..pi_clbk.COUNT
LOOP
dbms_output.put_line('i : '||i ||' '||pi_clbk(i).url);
FOR j IN 1..pi_clbk(i).domains.COUNT
LOOP
dbms_output.put_line('i : '||i || ' j : '||j ||' '||pi_clbk(i).uri_key);
dbms_output.put_line('i : '||i || ' j : '||j ||' '||pi_clbk(i).domains(j).domain_name);
dbms_output.put_line('i : '||i || ' j : '||j ||' '||pi_clbk(i).domains(j).domain_ip);
END LOOP;
END LOOP;
END;
/
Since this is being called from Java code and there they can create object with in object. I don't need to call this from PL-SQL side and I am saved.
Now, my question is how to call such procedure from PL-SQL? I want to call this procedure for the records returned by the Select Statement. Basically I need to store these values in the variable of type callbck.
You instantiate an object instance the same way you would do it in SQL, e.g:
select callbck
( callback_t
( 'www.abc.com'
, 12345
, domain_details_nt
( domain_details_ot('abc.com', domain_ip => '0.0.0.0')
, domain_details_ot('xyz.com', domain_ip => '0.0.0.1') ) )
, callback_t
( 'www.xyz.com'
, 23456
, domain_details_nt
( domain_details_ot('xyz.com', domain_ip => '0.0.0.2')
, domain_details_ot('abc.com', domain_ip => '0.0.0.3') ) )
)
from dual;
So, to call a procedure it would be something like
begin
get_callback_info(
callbck
( callback_t
( 'www.abc.com'
, 12345
, domain_details_nt
( domain_details_ot('abc.com', domain_ip => '0.0.0.0')
, domain_details_ot('xyz.com', domain_ip => '0.0.0.1') ) )
, callback_t
( 'www.xyz.com'
, 23456
, domain_details_nt
( domain_details_ot('xyz.com', domain_ip => '0.0.0.2')
, domain_details_ot('abc.com', domain_ip => '0.0.0.3') ) )
)
);
end;