http://qs321.pair.com?node_id=263821


in reply to Binding "Out" Parameters to Table Types for Oracle PL/SQL Stored Procedures

And the answer:

While one cannot pass back package-defined SQL variable types from Oracle stored procedures and functions, one can pass back cursors. And, you can define the cursor any way you see fit. So, here's how to accomplish the above.

First, you need to redefine the procedure to not return a "TABLE" type; rather, it should return a cursor (*note* I changed the procedure to a function because it seemed better that way now that it is just returning a var).

CREATE OR REPLACE PACKAGE foo AS TYPE deptCurs IS REF CURSOR; FUNCTION getAllDept RETURN foo.deptCurs; END foo;
Your package body, then simply becomes:
CREATE OR REPLACE PACKAGE BODY foo AS FUNCTION getDeptCurs RETURN foo.deptCurs IS crsr foo.deptCurs; BEGIN OPEN crsr FOR SELECT * FROM luDept; RETURN(crsr); END getDeptCurs; END foo;
To get at this from Perl, you use the following code:
my $dbh =DBI->connect('dbi:Oracle:host=hostname;sid=theSID', 'user', 'pass', { RaiseError => 1, AutoCommit => 0 }) || die "Database connection not made because:\n\t$DBI::errst +r\n"; my $deptRecords; eval { my $func = $dbh->prepare(q{ BEGIN :curs := foo.getDeptCurs(); END; }); # must specify the ora_type of ORA_RSET # so code knows it is a cursor $func->bind_param_inout(":curs ", \$deptRecords, 0, { ora_type => ORA_RSET}); $func->execute; $func->finish; }; if( $@ ) { warn "Execution of stored procedure failed because:\n\t$DBI::errstr +\n$@"; } while(my $hashRef = $deptRecords->fetchrow_hashref) { foreach(keys %$hashRef) { print "$_ is $hashRef->{$_}\n"; } } $deptRecords->finish; $dbh->disconnect;

I'll leave this here for posterity just in case anyone else ever stumbles upon this particular problem and encounters Warnock's Dilemma.

enoch