Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Looking for more efficient way to perform this simple query Expand / Collapse
Author
Message
Posted Friday, January 31, 2014 10:44 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, January 31, 2014 12:11 PM
Points: 2, Visits: 4
Hello -

As the subject states, I can't help but think there is a more efficient way to rewrite this query so that I don't have to perform the Counts twice, though my bag of SQL tricks is quite limited.

I am essentially trying to create a daily report which will grab the order counts for specific statuses for each user that has at least one order matching one of those statuses.

Any help is greatly appreciated!

-- Daily Report
SELECT u.UserID,
(SELECT COUNT(OrderID) FROM Orders WHERE OrderStatusID = 2) As Status2Count,
(SELECT COUNT(OrderID) FROM Orders WHERE OrderStatusID = 3) As Status3Count,
(SELECT COUNT(OrderID) FROM Orders WHERE OrderStatusID = 4) As Status4Count,
(SELECT COUNT(OrderID) FROM Orders WHERE OrderStatusID = 8) As Status8Count
FROM Users u
JOIN Orders o ON u.UserID = o.userID
WHERE (
((SELECT COUNT(*) FROM Orders WHERE OrderStatusID = 2) > 0) OR
((SELECT COUNT(*) FROM Orders WHERE OrderStatusID = 3) > 0) OR
((SELECT COUNT(*) FROM Orders WHERE OrderStatusID = 4) > 0) OR
((SELECT COUNT(*) FROM Orders WHERE OrderStatusID = 8) > 0)
)
GROUP BY u.UserID

Post #1536891
Posted Friday, January 31, 2014 11:09 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 2:39 PM
Points: 3,318, Visits: 7,166
There's an easier way and it's explained in this article: http://www.sqlservercentral.com/articles/T-SQL/63681/

This is an example that might not work because I have nothing to test on.
-- Daily Report
SELECT UserID,
SUM(CASE WHEN OrderStatusID = 2 THEN OrderCount END) As Status2Count,
SUM(CASE WHEN OrderStatusID = 3 THEN OrderCount END) As Status2Count,
SUM(CASE WHEN OrderStatusID = 4 THEN OrderCount END) As Status2Count,
SUM(CASE WHEN OrderStatusID = 8 THEN OrderCount END) As Status2Count,
FROM(
SELECT u.UserID,
o.OrderStatusID,
COUNT(*) OrderCount
FROM Users u
JOIN Orders o ON u.UserID = o.userID
WHERE OrderStatusID IN( 2, 3, 4, 8)
GROUP BY u.UserID, OrderStatusID
HAVING COUNT(*) > 0)x --This is a pre-aggregation to improve performance, but should be tested.
GROUP BY UserID

EDIT: I was evaluating wy word choice and easier might not be accurate when there's no practice on how to do it, but it's certainly more efficient and will come natural when you fully understand it.



Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1536904
Posted Friday, January 31, 2014 11:52 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, January 31, 2014 12:11 PM
Points: 2, Visits: 4
Thank you so much Luis!

This worked perfectly, makes more sense, and I appreciate the link.
Post #1536921
Posted Friday, January 31, 2014 12:17 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 2:39 PM
Points: 3,318, Visits: 7,166
You're welcome. I hope you understand how it works. If you don't, please post any questions that you have.


Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1536927
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse