Re: How to pass array of values to a stored procedure

From: "Tony Wasson" <ajwasson(at)gmail(dot)com>
To: "Curtis Scheer" <Curtis(at)daycos(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: How to pass array of values to a stored procedure
Date: 2006-07-18 17:33:58
Message-ID: 6d8daee30607181033g1c56b0b9x818087f6d5d4005c@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On 7/18/06, Tony Wasson <ajwasson(at)gmail(dot)com> wrote:
> On 7/18/06, Curtis Scheer <Curtis(at)daycos(dot)com> wrote:
> > Does anyone have any examples of how I would make a stored procedure in
> > plpgsql that would allow for passing a list or arrays of values to be used
> > in an sql IN clause? Like so: select * from table where field1 in (values).
> >

Ahhh... Here's an example using Tom's recommended field=ANY (arrayvalue) SQL.

CREATE TABLE ids
(
id INTEGER
, PRIMARY KEY (id)
);

INSERT INTO ids VALUES (1);
INSERT INTO ids VALUES (2);
INSERT INTO ids VALUES (3);

CREATE OR REPLACE FUNCTION example_array_input(INT[]) RETURNS SETOF ids AS
$BODY$
DECLARE
in_clause ALIAS FOR $1;
clause TEXT;
rec RECORD;
BEGIN
FOR rec IN SELECT id FROM ids WHERE id = ANY(in_clause)
LOOP
RETURN NEXT rec;
END LOOP;
-- final return
RETURN;
END
$BODY$ language plpgsql;

SELECT * FROM example_array_input('{1,2,4,5,6}'::INT[]);

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Emi Lu 2006-07-18 18:17:36 Re: Like with special character
Previous Message Tony Wasson 2006-07-18 17:24:36 Re: How to pass array of values to a stored procedure