Re: ALL() question - Mailing list pgsql-sql

From Osvaldo Rosario Kussama
Subject Re: ALL() question
Date
Msg-id 473B185B.2050502@yahoo.com.br
Whole thread Raw
In response to ALL() question  (Julien Cigar <jcigar@ulb.ac.be>)
List pgsql-sql
Julien Cigar escreveu:
> Hello,
> 
> I have a problem with the ALL() subquery expression.
> I have three tables:
> - specimens
> - test_bits
> - specimen_test_bits
> 
> The specimen_test_bits table contains two foreign keys, one to
> specimens(id), another to test_bits(id). 
> 
> Here is an output of specimen_test_bits:
> 
> muridae=> select * from specimen_test_bits;
>  specimen_id | test_bit_id 
> -------------+-------------
>        46096 |           1
>        46096 |           2
>        46096 |           3
>        46096 |           4
>        52894 |           1
>        52894 |           3
>        12546 |           2
> 
> What I would like is a query that returns all the specimen_id of 
> this table which have _all_ the given test_bit_id. So in this
> case, with test_bit_id 1,2,3,4 it should return only 
> specimen_id 46096.
> 
> With the following I got a syntax error:
> select specimen_id 
> from specimen_test_bits 
> where test_bit_id = all(1,2,3,4);
> 
> 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));
> 
> Any idea how I could do this ? I guess the problem is my ALL() expression ...
> 


Unclear, but works...

SELECT DISTINCT stb.specimen_id FROM specimen_test_bits stb WHERE NOT EXISTS (SELECT * FROM (VALUES (1), (2), (3) , 
(4)) AS foo(id)                    WHERE NOT EXISTS (SELECT 
stb1.test_bit_id FROM specimen_test_bits stb1                                       WHERE foo.id = 
stb1.test_bit_id                                         AND 
stb.specimen_id = stb1.specimen_id));

Osvaldo


pgsql-sql by date:

Previous
From: "Philippe Lang"
Date:
Subject: Re: Temporal databases
Next
From: "Tena Sakai"
Date:
Subject: postgres bogged down beyond tolerance