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

Поиск
Список
Период
Сортировка
От Richard Huxton
Тема Re: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures
Дата
Msg-id 49941AB5.9080307@archonet.com
обсуждение исходный текст
Ответ на Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures  (Gurjeet Singh <singh.gurjeet@gmail.com>)
Ответы Re: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures  (Gurjeet Singh <singh.gurjeet@gmail.com>)
Список pgsql-general
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

В списке pgsql-general по дате отправления:

Предыдущее
От: Gurjeet Singh
Дата:
Сообщение: Fwd: Need help in porting Oracle PL/SQL's OUT paramater based procedures
Следующее
От: Rory Campbell-Lange
Дата:
Сообщение: Re: Update table with random values from another table