SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


using ISNULL and SUM on the same column


using ISNULL and SUM on the same column

Author
Message
sjerromeharris
sjerromeharris
SSC Rookie
SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)

Group: General Forum Members
Points: 30 Visits: 50
I want to generate a report to compare the estimated_total_fee (on the usr_int1 table) with the amount the customer has actually been billed (from ac_billbook.costsnet).

Customers and their orders are identified by matters.entityref for the customer, and matters.number for the order number. Some customers may have had more than one bill generated on the same order; I don't need to know the details of every bill, just the total the customer has been billed for the one order so I'm using the Sum function.

However, I also need to account for orders that have not yet been billed so I want to include IsNull to allow for null values in the Ac_Billbook.costsnet column. I'm not sure how to phrase the syntax to allow for both Sum and IsNull on the same column.

SELECT
Matters.EntityRef,
Matters.Number,
usr_Int1.Estimated_total_fee,
Sum(Ac_Billbook.CostsNet) AS SumOfCostsNet

FROM
Ac_Billbook INNER JOIN
(Usr_Int1 INNER JOIN Matters ON
(Usr_Int1.MatterNo = Matters.Number)
AND (Usr_Int1.EntityRef = Matters.EntityRef))
ON (Ac_Billbook.MatterRef = Usr_Int1.MatterNo)
AND (Ac_Billbook.EntityRef = Usr_Int1.EntityRef)

Any help help gratefully received!
Thanks
Jack Corbett
  Jack Corbett
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44455 Visits: 14925
A couple of things:

1. You need a GROUP BY on your query.
2. You can address NULL values for Ac_Billbook.CostsNet 2 ways. You wrap the SUM with an ISNULL, ISNULL(Sum(Ac_Billbook.CostsNet), 0) because SUM ignores nulls when summing or you can reverse the SUM and ISNULL like this, Sum(ISNULL(Ac_Billbook.CostsNet, 0)) which will convert individual NULL's to 0. Doesn't really matter which one you do. The first might perform slightly better because the ISNULL is only being applied once. I've never actually tested it.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Phil Parker
Phil Parker
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 29
Jack Corbett (5/30/2012)
A couple of things:

1. You need a GROUP BY on your query.
2. You can address NULL values for Ac_Billbook.CostsNet 2 ways. You wrap the SUM with an ISNULL, ISNULL(Sum(Ac_Billbook.CostsNet), 0) because SUM ignores nulls when summing or you can reverse the SUM and ISNULL like this, Sum(ISNULL(Ac_Billbook.CostsNet, 0)) which will convert individual NULL's to 0. Doesn't really matter which one you do. The first might perform slightly better because the ISNULL is only being applied once. I've never actually tested it.


That's not actually true - they are not equivalent.

ISNULL(SUM(Ac_Billbook.CostsNet), 0) should be preferred - SUM will as you say ignore null values. However, if there are zero records to sum over, SUM will return NULL. Most of the time when doing a SUM you would want to treat zero records as having an aggregate sum of zero.
sumith1andonly1
sumith1andonly1
SSC-Addicted
SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)

Group: General Forum Members
Points: 460 Visits: 346
please add GROUP BY in your query



ISNULL(SUM(Ac_Billbook.CostsNet), 0)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search