From: | Adam Brusselback <adambrusselback(at)gmail(dot)com> |
---|---|
To: | pgsql-novice(at)lists(dot)postgresql(dot)org |
Subject: | Re: Calling oracle function from PostgreSQL |
Date: | 2024-09-02 14:50:33 |
Message-ID: | CAMjNa7eGhfXMPJ8PLvjRhzeTAU4gF5OMcy=uASzea4oXhXdDuw@mail.gmail.com |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-novice |
Re: That table hack
Oh man is scary as can be (to me). I think I would go with another option
(maybe outside of the database) entirely rather than introducing that into
my codebase.
Onto the general need:
I've definitely had the need for foreign function calls between my (both
Postgres) databases (e.g. dwh server calling a function to get some info
from oltp server), and I had to resort to dblink for that. Would have been
very nice if the FDW interface had support for functions / stored
procedures as first class citizens as long as the fdw implementation (and
other endpoint) support functions / stored procedures.
Once could dream.
-Adam
On Mon, Sep 2, 2024 at 9:34 AM Laurenz Albe <laurenz(dot)albe(at)cybertec(dot)at>
wrote:
> On Fri, 2024-08-30 at 12:38 +0530, Shweta Rahate wrote:
> > In my application there is a requirement to call the oracle function
> from PostgreSQL db.
> >
> > The oracle function should take the input from Postgres db and returns
> the output.
> > Please suggest a way to achieve this.
>
> There is no direct way to do this via oracle_fdw.
>
> There are, however, a couple of hacks to do that; see the following
> example:
>
> The Oracle function:
>
> CREATE OR REPLACE FUNCTION double(n NUMBER) RETURN NUMBER AS
> BEGIN
> RETURN n * 2;
> END;
> /
>
> Then I can define an Oracle table with a single row and a trigger on it:
>
> CREATE TABLE call_double(inp NUMBER, outp NUMBER);
>
> INSERT INTO call_double VALUES (1, 1);
>
> COMMIT;
>
> CREATE TRIGGER double_trig BEFORE UPDATE ON call_double FOR EACH ROW
> BEGIN
> :NEW.outp := double(:NEW.inp);
> END;
> /
>
> Now I can define a foreign table as follows:
>
> CREATE FOREIGN TABLE call_double(
> inp numeric OPTIONS (key 'true'),
> outp numeric)
> SERVER oracle OPTIONS (table 'CALL_DOUBLE');
>
> And then the following UPDATE calls the function and returns the result:
>
> UPDATE call_double SET inp = 12 RETURNING outp;
>
> That's ugly, but perhaps it is good enough as a workaround.
>
> Yours,
> Laurenz Albe
>
>
>
From | Date | Subject | |
---|---|---|---|
Next Message | Laszlo Forro | 2024-09-11 09:19:06 | Oracle -> Pg migration |
Previous Message | Laurenz Albe | 2024-09-02 13:34:37 | Re: Calling oracle function from PostgreSQL |