Thanks, Erik another possible solution would also be this.

Here it is in case you are interested.

On 7/18/06, Tony Wasson <[EMAIL PROTECTED]> wrote:
> On 7/18/06, Curtis Scheer <[EMAIL PROTECTED]> 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[]);

---------------------------(end of broadcast)---------------------------


>>Well, a good thing to note here is that there is a very distinct 
>>semantic difference between an array in postgres and what IN clauses 
>>take as input:  and array
>>is a data type whereas IN clauses take a parenthesized list of comma 
>>separated values.  So, if you  pass an array into a function wherein  
>>you then need
>>to use those values in an IN clause, you can build yourself an string of 
>>the values in the array, comma separated of course.

---------------------------(end of broadcast)---------------------------
TIP 4: Have you searched our list archives?

               http://archives.postgresql.org

Reply via email to