From: | Michael Fuhr <mike(at)fuhr(dot)org> |
---|---|
To: | "Michael L(dot) Hostbaek" <mich(at)the-lab(dot)org>, pgsql-sql(at)postgresql(dot)org |
Subject: | Re: Group by and aggregates |
Date: | 2004-11-04 17:31:53 |
Message-ID: | 20041104173153.GA20769@winnie.fuhr.org |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
On Thu, Nov 04, 2004 at 05:54:30PM +0100, Michael L. Hostbaek wrote:
> some_id partno status cmup qty
> 1 test1 stock 10.00 15
> 2 test2 incoming 12.00 10
> 3 test1 incoming 15.00 60
> 4 test1 incoming 14.00 11
>
> My SQL select statement will then group together partno, status and
> aggregate sum(qty) and max(cmup). This is all good and nice.
It would be helpful to see the exact query you're running. Based
on the query output you posted below, I'd guess your query looks
like this:
SELECT partno, status, MAX(cmup) AS cmup, SUM(qty) AS qty
FROM my_table
GROUP BY partno, status
ORDER BY partno, status DESC;
> My result will look something like this:
>
> partno status cmup qty
> test1 stock 10.00 15
> test1 incoming 15.00 71
> test2 incoming 12.00 10
>
> Now, I need the first line to say "15.00" in the cmup field. That is,
> stock and incoming are obviously not being grouped, but since it's the
> same partno I'd like somehow to show the highest cmup.
The query I posted above duplicates this output exactly. The cmup
field in the first record is 10.00 because that's the maximum value
of cmup where partno='test1' and status='stock', which is how I
(and presumably you) specified the grouping to work with GROUP BY.
Perhaps you want to group only by partno and not by status:
SELECT partno, MAX(cmup) AS cmup, SUM(qty) AS qty
FROM my_table
GROUP BY partno
ORDER BY partno;
partno | cmup | qty
--------+-------+-----
test1 | 15.00 | 86
test2 | 12.00 | 10
If that's not what you want, then please post the exact output
you're looking for. If you want to include the status field, then
please explain why a record for 'test1' and 'stock' should have a
MAX(cmup) of 15.00.
--
Michael Fuhr
http://www.fuhr.org/~mfuhr/
From | Date | Subject | |
---|---|---|---|
Next Message | Edmund Bacon | 2004-11-04 17:34:41 | Re: Group by and aggregates |
Previous Message | Sam Mason | 2004-11-04 17:25:08 | Re: Group by and aggregates |