Thread: PQexecParams and IN query?

PQexecParams and IN query?

From
Andrew McNamara
Date:
I'm trying to use PQexecParams to do an "IN" query, where the set of
values is supplied as a single parameter - essentially:
   SELECT * FROM sometable WHERE colvalue IN $1

With $1 as a set or array of some sort. Unfortunately, the above doesn't
pass parsing.  Is there any way to do an IN query via PQexecParams that
doesn't involve enumerating the set of values as individual parameters?

Previously, we were using PQexec(), and the adapter layer was conveniently
expanding the set into the command. 

-- 
Andrew McNamara, Senior Developer, Object Craft
http://www.object-craft.com.au/


Re: PQexecParams and IN query?

From
Gregory Stark
Date:
"Andrew McNamara" <andrewm@object-craft.com.au> writes:

> I'm trying to use PQexecParams to do an "IN" query, where the set of
> values is supplied as a single parameter - essentially:
>
>     SELECT * FROM sometable WHERE colvalue IN $1
>
> With $1 as a set or array of some sort. Unfortunately, the above doesn't
> pass parsing.  Is there any way to do an IN query via PQexecParams that
> doesn't involve enumerating the set of values as individual parameters?

No but there is a way to do something equivalent with arrays:

SELECT * FROM sometable WHERE colvalue = any($1::integer[]);

I'm not sure which (if any) drivers have good support for arrays though. I
think with most if not all drivers you'll have to crunch your list of elements
down into a string argument of the form "{1,2,3}" (without the quotes). 

If you're using something more complex than integers then you'll have to deal
with quoting the array elements which will start to get annoying.

--  Gregory Stark EnterpriseDB          http://www.enterprisedb.com



Re: PQexecParams and IN query?

From
Tom Lane
Date:
Gregory Stark <stark@enterprisedb.com> writes:
> "Andrew McNamara" <andrewm@object-craft.com.au> writes:
>> I'm trying to use PQexecParams to do an "IN" query, where the set of
>> values is supplied as a single parameter - essentially:
>> 
>> SELECT * FROM sometable WHERE colvalue IN $1
>> 
>> With $1 as a set or array of some sort. Unfortunately, the above doesn't
>> pass parsing.  Is there any way to do an IN query via PQexecParams that
>> doesn't involve enumerating the set of values as individual parameters?

> No but there is a way to do something equivalent with arrays:

> SELECT * FROM sometable WHERE colvalue = any($1::integer[]);

> I'm not sure which (if any) drivers have good support for arrays though.

Be aware also that if you're hoping that this will use an index on
colvalue, you need 8.2 or later to get such a plan from an "= any"
construct.
        regards, tom lane