Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: Silly SQL Question

RE: Silly SQL Question

From: Michael Milligan <Michael.Milligan_at_ingenix.com>
Date: Mon, 17 Nov 2003 11:44:25 -0800
Message-ID: <F001.005D6F24.20031117114425@fatcity.com>


Just a guess:

select distinct
  usr
from
  xxx
where
 (select

    count(*)
  from
    xxx
  group by Usr)
  =
 (select

    count(*)
    from
      xxx
    group by Usr, val)

-----Original Message-----
Sent: Thursday, November 13, 2003 3:29 PM To: Multiple recipients of list ORACLE-L

Gabriel Aragon wrote:
>
> I have a table with like this:
>
> Usr val
> ----------
> GAP 1
> GAP 5
> GAP 7
> JKL 8
> JKL 5
>
> I need a query that returns the user (GAP o JKL) that
> has ALL the values in a list. Example: Having the
> list: 1,5,7 the result will be GAP, but with the
> values 1,5 or 1,5,7,8 there will be no result.
>
> select distinct usr
> from xxx
> where val = All (1,3,5)
>
> I was trying the ALL operator but it works with part
> of the list, I need the user that has (exactly) all
> the values in the list. Any idea?
>
> Maybe it's a simple solution, but after several hours
> I feel blocked.
>
> TIA
> Gabriel
>

select usr
from XXX
where val in (list)
group by usr
having count(*) = number of values in list

does it but assumes that (usr, val) is unique (which can be easily worked-around :
select usr
from (select distinct usr, val

      from XXX)
group by ... )

and also that you know both the list and the number of items in the list, which looks reasonable.
If your intent is to build the queries and the list dynamically, I'd rather suggest storing the list into a temporary table.

-- 
Regards,

Stephane Faroult
Oriole Software
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Stephane Faroult
  INET: sfaroult_at_oriole.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).


This e-mail, including attachments, may include confidential and/or
proprietary information, and may be used only by the person or entity to
which it is addressed. If the reader of this e-mail is not the intended
recipient or his or her authorized agent, the reader is hereby notified that
any dissemination, distribution or copying of this e-mail is prohibited. If
you have received this e-mail in error, please notify the sender by replying
to this message and delete this e-mail immediately.
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Michael Milligan
  INET: Michael.Milligan_at_ingenix.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Mon Nov 17 2003 - 13:44:25 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US