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: Vladimir Begun <Vladimir.Begun_at_oracle.com>
Date: Thu, 13 Nov 2003 18:39:24 -0800
Message-ID: <F001.005D699B.20031113183924@fatcity.com>


Jacques

Yes, probably, you are right. I've overlooked example section, given by Gabriel.

DROP TABLE gab;
CREATE TABLE gab (usr VARCHAR2(10) NOT NULL, val NUMBER NOT NULL);

INSERT INTO gab VALUES('GAP', 1);
INSERT INTO gab VALUES('GAP', 5);
INSERT INTO gab VALUES('GAP', 5);
INSERT INTO gab VALUES('GAP', 7);

INSERT INTO gab VALUES('PAG', 1);

INSERT INTO gab VALUES('PAG', 7);
INSERT INTO gab VALUES('PAG', 2);
INSERT INTO gab VALUES('JKL', 1);
INSERT INTO gab VALUES('JKL', 5);
INSERT INTO gab VALUES('JKL', 5);

INSERT INTO gab VALUES('GPA', 1);
INSERT INTO gab VALUES('GPA', 5);

INSERT INTO gab VALUES('GPA', 7);
INSERT INTO gab VALUES('GPA', 8);
COMMIT; PL/SQL is not needed to solve this task as SQL task. There reason when it would be wise to rewrite it is out of scope of this topic (but the reason is obvious).

I'm just thinking that the query proposed by you is a bit expensive. So, I've re-scribbled mine:

SELECT usr

   FROM (

        SELECT DISTINCT usr, val, COUNT(DISTINCT val) OVER (PARTITION BY usr) cnt
          FROM gab
        )

  WHERE val IN (1, 5, 7)
    AND cnt = 3
  GROUP BY
        usr
      , cnt

HAVING COUNT(*) = cnt
/

HTH,

-- 
Vladimir Begun
The statements and opinions expressed here are my own and
do not necessarily represent those of Oracle Corporation.

Jacques Kilchoer wrote:


> Mr. Begun: I'm not convinced that your answer is quite the right one.
> I tried
> INSERT INTO gab VALUES ('GAP', 9) ;
> and then this query
> SELECT usr
> FROM (
> SELECT DISTINCT usr, val FROM gab
> )
> WHERE val IN (1, 5, 7)
> GROUP BY
> usr
> HAVING COUNT(*) = 3 -- number of elements in the list
> /
> returned the value 'GAP' even though 'GAP' has 4 "val"s in the table.
> The HAVING COUNT (*) = should also match the number of distinct rows for usr.
-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Vladimir Begun INET: Vladimir.Begun_at_oracle.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 Thu Nov 13 2003 - 20:39:24 CST

Original text of this message

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