Results 1 to 4 of 4
  1. #1
    Join Date
    Jun 2006
    Posts
    1

    Unanswered: Row-Limit per Group

    I need to sum() the 3 biggest values from a specific field of each group.

    Using

    Code:
    SELECT sum(numbers) FROM table GROUP BY field
    operates on every row and LIMIT only restricts the final result. What I need is a way to limit the rows per group.

  2. #2
    Join Date
    Apr 2002
    Location
    Toronto, Canada
    Posts
    20,002
    Code:
    select sum(numbers)
      from daTable as X   
     where ( select count(*) 
               from daTable 
              where numbers > X.numbers) < 3
    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL

  3. #3
    Join Date
    Sep 2004
    Location
    Belgium
    Posts
    1,126
    This only gives a single amount, i.e., the sum of the biggest three from the whole table.
    To obtain the sums of the three biggest values from each group:
    Code:
    SELECT field, sum(numbers)
    FROM   daTable as X
    WHERE  (SELECT count(*)
            FROM   daTable
            WHERE  field = X.field AND numbers > X.numbers) < 3
    GROUP BY field
    --_Peter Vanroose,
    __IBM Certified Database Administrator, DB2 9 for z/OS
    __IBM Certified Application Developer
    __ABIS Training and Consulting
    __http://www.abis.be/

  4. #4
    Join Date
    Apr 2002
    Location
    Toronto, Canada
    Posts
    20,002
    well spotted, peter, you are quite right, i misunderstood the question

    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •