Re: ALL() question

From: Richard Huxton <dev(at)archonet(dot)com>
To: Julien Cigar <jcigar(at)ulb(dot)ac(dot)be>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: ALL() question
Date: 2007-11-14 13:20:14
Message-ID: 473AF60E.8090403@archonet.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Julien Cigar wrote:
> On Wed, 2007-11-14 at 11:56 +0000, Richard Huxton wrote:
>> Julien Cigar wrote:
>>> What I would like is a query that returns all the specimen_id of
>>> this table which have _all_ the given test_bit_id.
>> [snip]
>>> With the following I got a syntax error:
>>> select specimen_id
>>> from specimen_test_bits
>>> where test_bit_id = all(1,2,3,4);
>> It's expecting an array here. You'd have to write
>> = all('{1,2,3,4}')
>> But that would have the same problem as...
>>
>>> The following works but no rows are returned :
>>> select specimen_id
>>> from specimen_test_bits
>>> where test_bit_id = all(select id from test_bits where id in (1,2,3,4));
>> It's testing each row individually and of course one row can't match ALL
>> four values.
>>
>> What you want to do is count the distinct values. Something like:
>>
>> SELECT
>> specimen_id
>> FROM foo
>> GROUP BY
>> specimen_id
>> HAVING
>> count(distinct test_bit_id) = 4
>> ;
>>
>
> I don't think it would work, for example if I have:
> specimen_id | test_bit_id
> ------------+------------
> 100 1
> 100 3
> 101 1
> 101 2
>
> the test_bit_ids are parameters, so with the given test_bit_id 1,3 it
> would return specimen_id 101 too, which I don't want ...

Not if you test for what you want too:

...
FROM foo
WHERE test_bit_id = ANY ('{1,3}')
...or...
WHERE test_bit_id IN (1,3)

> What I would like is the specimen_id which match _exactly_ the given
> test_bit_ids, so it should return only 100 in this example ..
>
> from the documentation ALL() can take a subquery too, not only an ARRAY
> (http://www.postgresql.org/docs/8.2/static/functions-subquery.html)

Yes, but that doesn't help with your query - one row can't match ALL
your values.

--
Richard Huxton
Archonet Ltd

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Richard Huxton 2007-11-14 13:21:10 Re: ALL() question
Previous Message Bart Degryse 2007-11-14 12:57:21 Re: ALL() question