Thread: Bad SUM result
-----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@SiliconTao.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-----
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';
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@SiliconTao.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@postgresql.org
There're no another ways? It don't looks like optimal. Petr Jezek ----- Original Message ----- From: "Jean-Luc Lachance" <jllachan@nsd.ca> To: "Roy Souther" <roy@silicontao.com> Cc: <pgsql-sql@postgresql.org> Sent: Monday, July 08, 2002 5:22 PM Subject: Re: [SQL] Bad SUM result > 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@SiliconTao.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@postgresql.org > > > > ---------------------------(end of broadcast)--------------------------- > TIP 6: Have you searched our list archives? > > http://archives.postgresql.org >