Re: plpgsql, dynamic variable lengths..

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Wells Oliver <wells(dot)oliver(at)gmail(dot)com>
Cc: pgsql-admin <pgsql-admin(at)postgresql(dot)org>
Subject: Re: plpgsql, dynamic variable lengths..
Date: 2020-02-08 02:09:44
Message-ID: 29969.1581127784@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

Wells Oliver <wells(dot)oliver(at)gmail(dot)com> writes:
> I am trying to create a plpgsql function which accepts a jsonb object as
> its parameter.

> This jsonb can have up to three keys, and I am trying to build out the
> dynamic SQL like this. I want to be able to pass a variable number of
> params to the RETURN QUERY EXECUTE ... USING ... because it can be 0 params
> in the JSONB object, or one, or two.

> What's the missing piece here? How can I adjust my USING to accomplish this?

I think your USING is probably fine. But you made all the SQL fragments
refer to $1:

> begin
> SQLSTRING := 'SELECT * FROM mytable WHERE true';
> if args->>'col1' is not null then
> SQLSTRING := SQLSTRING || ' AND col1 = $1';
> end if;

> if args->>'col2' is not null then
> SQLSTRING := SQLSTRING || ' AND col2 = $1';
> end if;

> if args->>'col3' is not null then
> SQLSTRING := SQLSTRING || ' AND col3 = $1';
> end if;

Of course those need to be $1, $2, $3.

regards, tom lane

In response to

Responses

Browse pgsql-admin by date

  From Date Subject
Next Message Wells Oliver 2020-02-08 02:23:31 Re: plpgsql, dynamic variable lengths..
Previous Message Wells Oliver 2020-02-08 00:38:12 plpgsql, dynamic variable lengths..