Thread: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures

Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures

From
Gurjeet Singh
Date:
(forgot to include general list earlier)

Hi All,

    I am involved in porting Spacewalk's backend DB schema from Oracle to Postgres. We are almost done with table migration, and are now attempting procedure/function porting.

A few things have been sorted out (link), and am now stuck with the OUT parameters! I saw the example of converting a PL/SQL function cs_parse_url, and see that finally it has been advised to use the ported version as

SELECT * FROM cs_parse_url('http://foobar.com/query.cgi?baz');

that is, not passing anything for the OUT or INOUT parameters. This works fine for a simple SELECT usage, but does not play well when this function is to be called from another function, (and assuming that it'd break the application code too, which uses Oracle syntax of calling functions)!

I have a simple function f() which I'd like to be ported in such a way that it works when called from other plpgsql code, as well as when the application uses the Oracle like syntax. Here's a sample usage of the function f() in Oracle:

<snip>
create or replace function f( a in out int, b out varchar ) return char as
begin
    a := 10;
    b := 'some string';
    return 'c';
end;
/

create or replace function f_caller return int as
    a int;
    b varchar(32);
begin
    dbms_output.put_line( f( a, b ) );
    dbms_output.put_line( a );
    dbms_output.put_line( b );
    return 0;
end;
/

set serveroutput on

select f_caller from dual;

  F_CALLER
----------
         0

c
10
some string
</snip>

Has anyone attempted porting PL/SQL, and if so, please share your experince with the OUT parameters.

Thanks and best regards,

PS: Postgres 8.1 is going to be the oldest supported version by Spacewalk.
--
gurjeet[.singh]@EnterpriseDB.com
singh.gurjeet@{ gmail | hotmail | indiatimes | yahoo }.com

EnterpriseDB      http://www.enterprisedb.com

Mail sent from my BlackLaptop device

Re: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures

From
Richard Huxton
Date:
Gurjeet Singh wrote:
> that is, not passing anything for the OUT or INOUT parameters. This works
> fine for a simple SELECT usage, but does not play well when this function is
> to be called from another function, (and assuming that it'd break the
> application code too, which uses Oracle syntax of calling functions)!
>
> I have a simple function f() which I'd like to be ported in such a way that
> it works when called from other plpgsql code, as well as when the
> application uses the Oracle like syntax. Here's a sample usage of the
> function f() in Oracle:

If you really want Oracle-compatible functions I think there's a company
that might sell you a solution :-)

However, failing that you'll want an example of OUT parameters in
PostgreSQL code - see below. The main thing to remember is that the OUT
is really just a shortcut way of defining a record type that gets
returned. It's nothing like passing by reference in <insert real
programming language here>.


BEGIN;

CREATE OR REPLACE FUNCTION f1(IN a integer, INOUT b integer, OUT c
integer) RETURNS RECORD AS $$
BEGIN
    c := a + b;
    b := b + 1;
    -- No values in RETURN
    RETURN;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION f2() RETURNS boolean AS $$
DECLARE
    a integer := 1;
    b integer := 2;
    c integer := -1;
    r RECORD;
BEGIN
    r := f1(a, b);
    -- Original variables unaffected
    RAISE NOTICE 'a=%, b=%, c=%', a,b,c;
    -- OUT params are here instead
    RAISE NOTICE 'r.b=%, r.c=%', r.b, r.c;

    -- This works, though notice we treat the function as a row-source
    SELECT (f1(a,b)).* INTO b,c;
    RAISE NOTICE 'a=%, b=%, c=%', a,b,c;

    RETURN true;
END;
$$ LANGUAGE plpgsql;

SELECT f2();

ROLLBACK;

--
  Richard Huxton
  Archonet Ltd

Re: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures

From
Gurjeet Singh
Date:
On Thu, Feb 12, 2009 at 6:18 PM, Richard Huxton <dev@archonet.com> wrote:
Gurjeet Singh wrote:
> that is, not passing anything for the OUT or INOUT parameters. This works
> fine for a simple SELECT usage, but does not play well when this function is
> to be called from another function, (and assuming that it'd break the
> application code too, which uses Oracle syntax of calling functions)!
>
> I have a simple function f() which I'd like to be ported in such a way that
> it works when called from other plpgsql code, as well as when the
> application uses the Oracle like syntax. Here's a sample usage of the
> function f() in Oracle:

If you really want Oracle-compatible functions I think there's a company
that might sell you a solution :-)

:) Spacewalk is not interested you see.
 


However, failing that you'll want an example of OUT parameters in
PostgreSQL code - see below. The main thing to remember is that the OUT
is really just a shortcut way of defining a record type that gets
returned. It's nothing like passing by reference in <insert real
programming language here>.


BEGIN;

CREATE OR REPLACE FUNCTION f1(IN a integer, INOUT b integer, OUT c
integer) RETURNS RECORD AS $$
BEGIN
   c := a + b;
   b := b + 1;
   -- No values in RETURN
   RETURN;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION f2() RETURNS boolean AS $$
DECLARE
   a integer := 1;
   b integer := 2;
   c integer := -1;
   r RECORD;
BEGIN
   r := f1(a, b);
   -- Original variables unaffected
   RAISE NOTICE 'a=%, b=%, c=%', a,b,c;
   -- OUT params are here instead
   RAISE NOTICE 'r.b=%, r.c=%', r.b, r.c;

   -- This works, though notice we treat the function as a row-source
   SELECT (f1(a,b)).* INTO b,c;
   RAISE NOTICE 'a=%, b=%, c=%', a,b,c;

   RETURN true;
END;
$$ LANGUAGE plpgsql;

SELECT f2();

ROLLBACK;

You see, you did not pass the third (OUT) parameter when calling the function:

   r := f1(a, b);

This differs from Oracle syntax where you _need_ to pass the third parameter.

And what if the Oracle function actually returns a value too? How do we handle that in the application, because we can't declare RECORD vars in Java/perl/python etc.

Thanks and best regards,
--
gurjeet[.singh]@EnterpriseDB.com
singh.gurjeet@{ gmail | hotmail | indiatimes | yahoo }.com

EnterpriseDB      http://www.enterprisedb.com

Mail sent from my BlackLaptop device

Re: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures

From
Richard Huxton
Date:
Removed -hackers from the mailing-lists. Just noticed it, and I think
this is probably fine on the general list.

Gurjeet Singh wrote:
> On Thu, Feb 12, 2009 at 6:18 PM, Richard Huxton <dev@archonet.com> wrote:

>> CREATE OR REPLACE FUNCTION f1(IN a integer, INOUT b integer, OUT c
>> integer) RETURNS RECORD AS $$

> You see, you did not pass the third (OUT) parameter when calling the
> function:
>
>    r := f1(a, b);
>
> This differs from Oracle syntax where you _need_ to pass the third
> parameter.

That's because pl/pgsql isn't pl/sql. If you want to keep close, you can
just declare "c" as INOUT.

The original problem was that it was a pain to declare types for every
function that returned more than just a simple scalar. The alternative
was to say you returned RECORD, but then you needed to list column-names
when calling the function. Finally, IN/OUT/INOUT was abused to provide
an implicit record-type declaration for you. It's convenient for simple
cases, but it's not actually what I think of as IN/OUT parameters.

> And what if the Oracle function actually returns a value too? How do we
> handle that in the application, because we can't declare RECORD vars in
> Java/perl/python etc.

You can always do something like: SELECT b,c FROM f1(1, 2);


Realistically, I don't think you're going to get one set of queries
running against both RDBMS.

--
  Richard Huxton
  Archonet Ltd