Re: Bad SUM result

From: Jean-Luc Lachance <jllachan(at)nsd(dot)ca>
To: Roy Souther <roy(at)silicontao(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Bad SUM result
Date: 2002-07-08 15:22:31
Message-ID: 3D29AE37.ADE9D534@nsd.ca
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

That is because your query is generating a cartesian product.

Try:

SELECT (
SELECT SUM(totalprice)
FROM invoices
WHERE custnumber = '1'
) - (
SELECT SUM(paymentamount)
FROM payments
WHERE custnumber = '1'
)

Roy Souther wrote:
>
> -----BEGIN PGP SIGNED MESSAGE-----
> Hash: SHA1
>
> 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.
>
> 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.
> - --
> Roy Souther <roy(at)SiliconTao(dot)com>
> http://www.SiliconTao.com
>
> Linux: May the source be with you.
>
> -----BEGIN PGP SIGNATURE-----
> Version: GnuPG v1.0.6 (GNU/Linux)
> Comment: For info see http://www.gnupg.org
>
> iEYEARECAAYFAj0oo9MACgkQCbnxcmEBt43qFQCgtjCs7khKGH+2LYd78O9mA3h4
> vDQAn0GkKkuYl1Kybgm/ITO4LbO1WWLX
> =1G4R
> -----END PGP SIGNATURE-----
>
> ---------------------------(end of broadcast)---------------------------
> TIP 1: subscribe and unsubscribe commands go to majordomo(at)postgresql(dot)org

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Joachim Trinkwitz 2002-07-08 15:49:56 Re: INSERT only under certain conditions (SELECT)
Previous Message Kevin Brannen 2002-07-08 15:10:46 Re: bit field changes in 7.2.1