improvise callbacks in plpgsql

Lists: pgsql-performance
From: "Merlin Moncure" <merlin(dot)moncure(at)rcsonline(dot)com>
To: <pgsql-performance(at)postgresql(dot)org>
Subject: improvise callbacks in plpgsql
Date: 2005-11-01 19:00:00
Message-ID: 6EE64EF3AB31D5448D0007DD34EEB3417DD754@Herge.rcsinc.local
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

hello performance minded administrators:

We have recently converted a number of routines that walk a bill of
materials (which is a nested structure) from the application side to the
server side via recursive plpgsql functions. The performance is
absolutely fantastic but I have to maintain a specialized 'walker' for
each specific task that I have to do. It would be very nice and elegant
if I could pass in the function for the walker to execute while it is
iterating through the bill of materials. I have been beating my head
against the wall for the best way to do this so here I am shopping for
ideas.

A simplified idealized version of what I would like to do is
begin
select (callback_routine)(record_type)
end;

from within a plpgsql function. I am borrowing the C syntax for a
function pointer here. The problem I am running into is the only way to
do callbacks is via dynamic sql...however you can use higher level types
such as row/record type in dynamic sql (at least not efficiently). I
could of course make a full dynamic sql call by expanding the record
type into a large parameter list but this is unwieldy and brittle.

Any thoughts?

Merlin


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: "Merlin Moncure" <merlin(dot)moncure(at)rcsonline(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: improvise callbacks in plpgsql
Date: 2005-11-01 21:29:22
Message-ID: 28343.1130880562@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

"Merlin Moncure" <merlin(dot)moncure(at)rcsonline(dot)com> writes:
> A simplified idealized version of what I would like to do is
> begin
> select (callback_routine)(record_type)
> end;
> from within a plpgsql function. I am borrowing the C syntax for a
> function pointer here.

Well, there's no function pointer type in SQL :-(. I don't see any way
to do what you want in pure plpgsql. If you're willing to implement an
auxiliary C function you could probably make it go:

create function callit(oid, record) returns void ...

where the OID has to be the OID of a function taking a record-type
argument. The regprocedure pseudotype would allow you not to need
to write any numeric OIDs in your code:

select callit('myfunc(record)'::regprocedure, recordvar);

The body of callit() need be little more than OidFunctionCall1()
plus whatever error checking and security checking you want to
include.

regards, tom lane