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).
Here's a very simple example. However, I think passing arrays of INTs
around is dirty. I wasn't able to do this without a FOR ...IN EXECUTE
statement.
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
-- conver the array to a text string and make it LOOK like an
IN statement
clause := in_clause;
clause := trim(leading '{' FROM clause);
clause := trim(trailing '}' FROM clause);
FOR rec IN EXECUTE 'SELECT id FROM ids WHERE id 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)---------------------------
TIP 5: don't forget to increase your free space map settings