Beefy Boxes and Bandwidth Generously Provided by pair Networks
Just another Perl shrine
 
PerlMonks  

comment on

( [id://3333]=superdoc: print w/replies, xml ) Need Help??

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

In reply to Re: Binding "Out" Parameters to Table Types for Oracle PL/SQL Stored Procedures by enoch
in thread Binding "Out" Parameters to Table Types for Oracle PL/SQL Stored Procedures by enoch

Title:
Use:  <p> text here (a paragraph) </p>
and:  <code> code here </code>
to format your post; it's "PerlMonks-approved HTML":



  • Are you posting in the right place? Check out Where do I post X? to know for sure.
  • Posts may use any of the Perl Monks Approved HTML tags. Currently these include the following:
    <code> <a> <b> <big> <blockquote> <br /> <dd> <dl> <dt> <em> <font> <h1> <h2> <h3> <h4> <h5> <h6> <hr /> <i> <li> <nbsp> <ol> <p> <small> <strike> <strong> <sub> <sup> <table> <td> <th> <tr> <tt> <u> <ul>
  • Snippets of code should be wrapped in <code> tags not <pre> tags. In fact, <pre> tags should generally be avoided. If they must be used, extreme care should be taken to ensure that their contents do not have long lines (<70 chars), in order to prevent horizontal scrolling (and possible janitor intervention).
  • Want more info? How to link or How to display code and escape characters are good places to start.
Log In?
Username:
Password:

What's my password?
Create A New User
Domain Nodelet?
Chatterbox?
and the web crawler heard nothing...

How do I use this?Last hourOther CB clients
Other Users?
Others admiring the Monastery: (2)
As of 2024-04-17 06:27 GMT
Sections?
Information?
Find Nodes?
Leftovers?
    Voting Booth?

    No recent polls found