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

From: Richard Huxton <dev(at)archonet(dot)com>
To: Gurjeet Singh <singh(dot)gurjeet(at)gmail(dot)com>
Cc: PGSQL Hackers <pgsql-hackers(at)postgresql(dot)org>, PGSQL General <pgsql-general(at)postgresql(dot)org>
Subject: Re: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures
Date: 2009-02-12 12:48:53
Message-ID: 49941AB5.9080307@archonet.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general pgsql-hackers

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

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Rory Campbell-Lange 2009-02-12 13:10:05 Re: Update table with random values from another table
Previous Message Rory Campbell-Lange 2009-02-12 12:44:31 Update table with random values from another table

Browse pgsql-hackers by date

  From Date Subject
Next Message Magnus Hagander 2009-02-12 12:54:13 Re: mingw check hung
Previous Message Heikki Linnakangas 2009-02-12 12:23:58 Re: Hot Standby: subxid cache changes