> > CREATE OR REPLACE FUNCTION getval(integer) > RETURNS SETOF id_val_tbl AS > $BODY$ > select * from id_bal_tbl where ( $1 is null )or (id=$1 ); $BODY$ > LANGUAGE 'sql' VOLATILE SECURITY DEFINER; > > > It works fine, however an index is never used (if just one > record is requested). The column id has a btree-Index but > what aobut it. I'm wondering how this comes and how one can > overcome this limit.
The reason why the query worked as plain query may come from the fact that NULL IS NULL was evaluated to constant FALSE and optimized out from OR. In case of function the query was planned before substituting parameters, so the OR was still there and prevented index scan. Standard technique is to rewrite OR queries to UNION queries. I believe PostgreSQL optimizer does not do that automatically. So you could try instead: select * from id_bal_tbl where $1 is null union all select * from id_bal_tbl where id = $1; (Note: in general you would need UNION without ALL, to keep the semantics of OR.) Tambet ---------------------------(end of broadcast)--------------------------- TIP 6: Have you searched our list archives? http://archives.postgresql.org