Re: Bad SUM result
От | Stephan Szabo |
---|---|
Тема | Re: Bad SUM result |
Дата | |
Msg-id | 20020707133824.L19117-100000@megazone23.bigpanda.com обсуждение исходный текст |
Ответ на | Bad SUM result (Roy Souther <roy@silicontao.com>) |
Список | pgsql-sql |
On Sun, 7 Jul 2002, Roy Souther wrote: > I have an invoice database that has two tables one for invoices and one for > payments. I want to get the account balance for a client by subtracting the > sum of all payments from the sum off all invoices for that client. > > Here is the SQL that I thought should work. > SELECT SUM(t0.totalprice)-SUM(t1.paymentamount) FROM invoices t0, payments t1 > WHERE t0.custnumber='1' AND t1.custnumber='1' > > It works fine if there is only one invoice and one payment but as soon as > there is more then one of either it screws up. For each match found in > payments the invoice sum is added to the total. So if client 1 purchased a > $100 item then maid a $10 payment the SQL would return the balance of $90 > just fine. When the client makes a second payment of $15 the balance is $75 > but this SQL returns ($100+$100)-($10+$15) = $175. A third payment of $1 > would return ($100+$100+$100)-($10+$15+$1) = $274. Right, because you're doing a join that ends up with 100 | 10 100 | 15 100 | 1 as the effective rows. > Could some one explain this to me and recommend an SQL command that would work > please? I could do this using a temp table but that would be very messy as I > would really like it to be a single SQL command. Maybe something like: select sum(amt) from (select custnumber, totalprice as amt from invoices union select custnumber, -paymentamount as amt from payments) as c where custnumber='1';
В списке pgsql-sql по дате отправления: