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


COUNT and compare


COUNT and compare

Author
Message
support 86837
support 86837
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 17
For some reason I've always gotten confuses when using COUNT!

I have two tables, one for Orders and then an Assiged Parcels table which can have multiple records attached to an Order. In the Order table is column Pieces, which must match the count for Assigned Parcels. I also need to make the Orders table 'clickable' in the results.

Here is my code. What am I doing wrong?

SELECT PA.OrderID, COUNT(PA.OrderID) AS 'TotalParcels'
FROM tblParcelAssigned as PA
INNER JOIN tblOrder AS O ON O.OrderID = PA.OrderID
WHERE PA.Type = 2
AND O.Pieces <> TotalParcels
GROUP BY PA.OrderID
ORDER BY PA.OrderID DESC

Thanks from Newbie Dan!
Evil Kraig F
Evil Kraig F
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8555 Visits: 7660
support 86837 (12/18/2012)

I have two tables, one for Orders and then an Assiged Parcels table which can have multiple records attached to an Order. In the Order table is column Pieces, which must match the count for Assigned Parcels.
Here is my code. What am I doing wrong?


It's an Order of Evaluation issue. You use the WHERE clause to filter what goes into the aggregation, then you use the HAVING clause to filter the results of the aggregation, like so:


SELECT
PA.OrderID,
COUNT(*) AS 'TotalParcels'
FROM
tblParcelAssigned as PA
INNER JOIN
tblOrder AS O
ON O.OrderID = PA.OrderID
WHERE
PA.Type = 2
HAVING
o.Pieces <> Count(*)
GROUP BY
PA.OrderID
ORDER BY
PA.OrderID
DESC



I also need to make the Orders table 'clickable' in the results.


I'm not entirely sure what you mean by this.


- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
support 86837
support 86837
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 17
Your query works only if I omit the HAVING clause.
Evil Kraig F
Evil Kraig F
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8555 Visits: 7660
support 86837 (12/18/2012)
Your query works only if I omit the HAVING clause.


What error are you getting? You're getting untested code as I don't have a sample set to work from for your particular issue. If you check the first link in my signature, you'll see how we usually ask for code assistance requests like this to be setup so we can get you tested code.


- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)SSCertifiable (7.2K reputation)

Group: General Forum Members
Points: 7217 Visits: 6431
Evil Kraig F (12/18/2012)
support 86837 (12/18/2012)

I have two tables, one for Orders and then an Assiged Parcels table which can have multiple records attached to an Order. In the Order table is column Pieces, which must match the count for Assigned Parcels.
Here is my code. What am I doing wrong?


It's an Order of Evaluation issue. You use the WHERE clause to filter what goes into the aggregation, then you use the HAVING clause to filter the results of the aggregation, like so:


SELECT
PA.OrderID,
COUNT(*) AS 'TotalParcels'
FROM
tblParcelAssigned as PA
INNER JOIN
tblOrder AS O
ON O.OrderID = PA.OrderID
WHERE
PA.Type = 2
HAVING
o.Pieces <> Count(*)
GROUP BY
PA.OrderID
ORDER BY
PA.OrderID
DESC



I also need to make the Orders table 'clickable' in the results.


I'm not entirely sure what you mean by this.


I think the problem may be that HAVING needs to be after GROUP BY.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
support 86837
support 86837
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 17
That doesn't seem to work either. After dropping and adding lines to the code, it seems that the comparison line is where it hiccups.

Here is an example where I get the columns to display side by side. Still, the HAVING is where I don't yet have it. If I omit the HAVING, the query runs fine.

SELECT
O.OrderID,
O.Pieces,
PA.OrderID,
COUNT(PA.OrderID) AS TotalParcels,
COUNT(*) AS 'TotalParcels'
FROM
tblParcelAssigned as PA
INNER JOIN
tblOrder AS O
ON O.OrderID = PA.OrderID
WHERE
PA.Type = 2
-- HAVING
-- o.Pieces <> Count(*)
GROUP BY
O.OrderID,
O.Pieces,
PA.OrderID
ORDER BY
PA.OrderID
DESC
support 86837
support 86837
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 17
By the way, the indentations in my code display fine when I edit my post, but the final version has them all lined up without colors or indents. Not sure what I'm doing wrong!
Evil Kraig F
Evil Kraig F
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8555 Visits: 7660
Use the code="sql" IfCode on the left, like so. Dwain's right, I flipped the order for having/group by, need to put it after.


SELECT 
O.OrderID,
O.Pieces,
PA.OrderID,
COUNT(PA.OrderID) AS TotalParcels,
COUNT(*) AS 'TotalParcels'
FROM
tblParcelAssigned as PA
INNER JOIN
tblOrder AS O
ON O.OrderID = PA.OrderID
WHERE
PA.Type = 2
GROUP BY
O.OrderID,
O.Pieces,
PA.OrderID
HAVING
o.Pieces <> Count(*)
ORDER BY
PA.OrderID
DESC




- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
support 86837
support 86837
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 17
Thank you everyone for your help. I'm sure I'll get better at this the more I practice. I've referred those who've offered me accoldes to this thread.

Dan
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