Thread: How do you write this query?

How do you write this query?

From
Wei Weng
Date:
I have a table 
                Table "test"
Column    |            Type        | Modifiers
--------+------------------------+----------
data    | integer                | not null 
data1   | character varying(128) | not null
data2   | character varying(128) | not null

(Note: data is NOT the primary key.)

And 
select * from test 
returns

data | data1 | data2 
------+-------+-------   1 | foo   | bar    2 | greg  | bar   3 | pooh  | bar   4 | dah   | peng

I need a query that returns me the "data1" that satisfies the logic of
the following pseudo code:

1: select data2 into @out from test where data1 = 'pooh'
2: select data1 from test where data2 = @out and data = 3


What do I do?

Thanks!

-- 
Wei Weng
Network Software Engineer
KenCast Inc.




Re: How do you write this query?

From
Richard Huxton
Date:
On Thursday 31 Oct 2002 6:21 pm, Wei Weng wrote:
>  data | data1 | data2
> ------+-------+-------
>     1 | foo   | bar
>     2 | greg  | bar
>     3 | pooh  | bar
>     4 | dah   | peng
>
> I need a query that returns me the "data1" that satisfies the logic of
> the following pseudo code:
>
> 1: select data2 into @out from test where data1 = 'pooh'
> 2: select data1 from test where data2 = @out and data = 3

The most literal would be something like:

SELECT t1.data1 FROM test t1
WHERE t1.data=3 AND t1.data2 IN   (SELECT t2.data2    FROM test t2    WHERE t2.data1='pooh')

You can probably get away without the t1/t2 stuff but that should make things
clear.

Since Postgresql isn't very good at optimising IN, you might want to rewrite
it as an EXISTS query instead - see the manuals and mailing list archives for
details.

HTH
--  Richard Huxton


Re: How do you write this query?

From
Jean-Luc Lachance
Date:
Thank goodness for nested select!

select data1 from test where data2 = ( select distinct data2 from test
where data1 = 'pooh') and data = 3;

JLL

Richard Huxton wrote:
> 
> On Thursday 31 Oct 2002 6:21 pm, Wei Weng wrote:
> >  data | data1 | data2
> > ------+-------+-------
> >     1 | foo   | bar
> >     2 | greg  | bar
> >     3 | pooh  | bar
> >     4 | dah   | peng
> >
> > I need a query that returns me the "data1" that satisfies the logic of
> > the following pseudo code:
> >
> > 1: select data2 into @out from test where data1 = 'pooh'
> > 2: select data1 from test where data2 = @out and data = 3
> 
> The most literal would be something like:
> 
> SELECT t1.data1 FROM test t1
> WHERE t1.data=3 AND t1.data2 IN
>     (SELECT t2.data2
>     FROM test t2
>     WHERE t2.data1='pooh')
> 
> You can probably get away without the t1/t2 stuff but that should make things
> clear.
> 
> Since Postgresql isn't very good at optimising IN, you might want to rewrite
> it as an EXISTS query instead - see the manuals and mailing list archives for
> details.
> 
> HTH
> --
>   Richard Huxton
> 
> ---------------------------(end of broadcast)---------------------------
> TIP 5: Have you checked our extensive FAQ?
> 
> http://www.postgresql.org/users-lounge/docs/faq.html


Re: How do you write this query?

From
Achilleus Mantzios
Date:
On 31 Oct 2002, Wei Weng wrote:

and yet another equivalent query:

SELECT f1.data1 from test f1,test f2 where f1.data=3 and f1.data2 =
f2.data2 and f2.data1='pooh';

> I have a table
>
>                  Table "test"
> Column    |            Type        | Modifiers
> --------+------------------------+----------
> data    | integer                | not null
> data1   | character varying(128) | not null
> data2   | character varying(128) | not null
>
> (Note: data is NOT the primary key.)
>
> And
> select * from test
> returns
>
>
>  data | data1 | data2
> ------+-------+-------
>     1 | foo   | bar
>     2 | greg  | bar
>     3 | pooh  | bar
>     4 | dah   | peng
>
> I need a query that returns me the "data1" that satisfies the logic of
> the following pseudo code:
>
> 1: select data2 into @out from test where data1 = 'pooh'
> 2: select data1 from test where data2 = @out and data = 3
>
>
> What do I do?
>
> Thanks!
>
> --
> Wei Weng
> Network Software Engineer
> KenCast Inc.
>
>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 3: if posting/reading through Usenet, please send an appropriate
> subscribe-nomail command to majordomo@postgresql.org so that your
> message can get through to the mailing list cleanly
>

==================================================================
Achilleus Mantzios
S/W Engineer
IT dept
Dynacom Tankers Mngmt
Nikis 4, Glyfada
Athens 16610
Greece
tel:    +30-10-8981112
fax:    +30-10-8981877
email:  achill@matrix.gatewaynet.com       mantzios@softlab.ece.ntua.gr