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: finding the smallest average with an analytic function - is i

RE: finding the smallest average with an analytic function - is i

From: Jamadagni, Rajendra <Rajendra.Jamadagni_at_espn.com>
Date: Mon, 19 May 2003 13:06:48 -0800
Message-ID: <F001.0059D096.20030519130648@fatcity.com>


something like ...
SELECT *
  FROM (SELECT NAME NAME, AVG(VALUE) avg_value

          FROM x 
         GROUP BY NAME 
         ORDER BY 2) 

 WHERE ROWNUM < 2
/

or

SELECT NAME, avg_value
FROM
(SELECT NAME NAME, AVG(VALUE) avg_value, rank() OVER(ORDER BY AVG(VALUE)) rk   FROM x GROUP BY NAME)
WHERE rk = 1
/
Raj




Rajendra dot Jamadagni at nospamespn dot com All Views expressed in this email are strictly personal. QOTD: Any clod can have facts, having an opinion is an art ! -----Original Message-----
Sent: Monday, May 19, 2003 3:37 PM
To: Multiple recipients of list ORACLE-L

I want to find the name having the smallest average value. Is it possible to do it using analytic functions? Is it possible to do it using analytic functions WITHOUT a sub-select?
create table x (name varchar2 (4), value number) ;

insert into x (name, value) values ('A', 2) ; 
insert into x (name, value) values ('A', 3) ; 
insert into x (name, value) values ('A', 4) ; 
insert into x (name, value) values ('B', 1) ; 
insert into x (name, value) values ('B', 2) ; 
insert into x (name, value) values ('B', 3) ; 
insert into x (name, value) values ('C', 3) ; 
insert into x (name, value) values ('C', 4) ; 
insert into x (name, value) values ('C', 5) ; 
insert into x (name, value) values ('C', 6) ; 

-- is it possible to rewrite the query below using analytic functions?
select name, avg (value)
from x
group by name
having avg (value) = (select min (avg (value)) from x group by name) ; Expected output:
NAME AVG(VALUE)
---- ----------
B 2

--

Please see the official ORACLE-L FAQ: http://www.orafaq.net
--

Author: Jamadagni, Rajendra
  INET: Rajendra.Jamadagni_at_espn.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 May 19 2003 - 16:06:48 CDT

Original text of this message

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