Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


sorting by month with current month at top


sorting by month with current month at top

Author
Message
S_Kumar_S
S_Kumar_S
SSC-Addicted
SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)

Group: General Forum Members
Points: 414 Visits: 1062
Hi
In one of my query I need data to be sorted starting with current month. Here is sample script:
create table OrderTest(OrderDate datetime,orderCount int)
GO
insert into OrderTest values('2013/10/15',30)
insert into OrderTest values('2013/10/17',40)
insert into OrderTest values('2013/09/13',60)
insert into OrderTest values('2013/08/21',45)
insert into OrderTest values('2013/07/13',38)
insert into OrderTest values('2013/06/15',23)
insert into OrderTest values('2013/05/15',56)
insert into OrderTest values('2013/04/15',267)
insert into OrderTest values('2013/03/19',67)
insert into OrderTest values('2013/02/15',45)
insert into OrderTest values('2013/01/15',90)
insert into OrderTest values('2012/11/15',22)
insert into OrderTest values('2012/12/15',76)
GO

select datepart(mm,OrderDate) MonthNum,AVG(orderCount) AvgOrderCount
FROM OrderTest
GROUP BY datepart(mm,OrderDate)
Order BY datepart(mm,OrderDate)


I need data like:
10 30
11 22
12 76
1 90
2 45
3 67
4 267
5 56
6 23
7 38
8 45
9 60


thanks

-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
LutzM
LutzM
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 7001 Visits: 13559
What is your expected output if we'd add another row like INSERT INTO OrderTest VALUES('2011/11/17',11) ?
Your current query only aggregate by month, so the above value will be added to the month November, together with the data for year 2012.
Is this intended?



Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
S_Kumar_S
S_Kumar_S
SSC-Addicted
SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)

Group: General Forum Members
Points: 414 Visits: 1062
oh, ok. Sorry I should have mentioned it. There will be where caluse , SO that the query only picks current one year data.
So there will always be 12 months data in resultset.

-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
LutzM
LutzM
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 7001 Visits: 13559
Something like this (I used a cte to get a sort criteria added to the group by statement that is omitted in the final output)?
WITH cte as
(
SELECT datepart(mm,OrderDate) MonthNum,AVG(orderCount) AvgOrderCount, MIN(OrderDate) as m_date
FROM OrderTest
GROUP BY datepart(mm,OrderDate)
)
SELECT MonthNum,AvgOrderCount
FROM cte
Order BY m_date





Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
S_Kumar_S
S_Kumar_S
SSC-Addicted
SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)

Group: General Forum Members
Points: 414 Visits: 1062
Thanks So much. it worked. But I think the order by clause should have been:
Order BY m_date desc

So that I get current month at top.

-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
LutzM
LutzM
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 7001 Visits: 13559
Yep, you're correct.
That's one of the pitfalls when not seeing the complete date - I totally missed the sort order. Sorry.



Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
J Livingston SQL
J Livingston SQL
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3448 Visits: 33029
bit late......


SELECT DATEPART(mm, OrderDate) AS MonthNum, AVG(orderCount) AS AvgOrderCount
FROM OrderTest
GROUP BY DATEPART(mm, OrderDate), DATEADD(mm, DATEDIFF(mm, 0, OrderDate), 0)
ORDER BY DATEADD(mm, DATEDIFF(mm, 0, OrderDate), 0) DESC



________________________________________________________________
you can lead a user to data....but you cannot make them think
and remember....every day is a school day

LutzM
LutzM
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 7001 Visits: 13559
J Livingston SQL (10/14/2013)
bit late......


SELECT DATEPART(mm, OrderDate) AS MonthNum, AVG(orderCount) AS AvgOrderCount
FROM OrderTest
GROUP BY DATEPART(mm, OrderDate), DATEADD(mm, DATEDIFF(mm, 0, OrderDate), 0)
ORDER BY DATEADD(mm, DATEDIFF(mm, 0, OrderDate), 0) DESC



Agreed, more efficient (avoids one sort operation).

Edit: but it requires to guarantee only 12 month in the data set (as mentioned before). Otherwise it'll return more than 12 rows.



Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
S_Kumar_S
S_Kumar_S
SSC-Addicted
SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)

Group: General Forum Members
Points: 414 Visits: 1062
Perfect..perfect..

-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)

Group: General Forum Members
Points: 4253 Visits: 6431
S_Kumar_S (10/14/2013)
Perfect..perfect..


Really? I would have thought from your expected results you'd want something more like this:


SELECT TOP 12 DATEPART(mm, OrderDate) AS MonthNum, AVG(orderCount) AS AvgOrderCount
FROM OrderTest
GROUP BY DATEPART(mm, OrderDate), DATEDIFF(mm, 0, OrderDate)
ORDER BY
CASE
WHEN DATEDIFF(mm, 0, GETDATE()) = DATEDIFF(mm, 0, OrderDate) THEN 0
WHEN DATEDIFF(mm, 0, GETDATE()) - DATEDIFF(mm, 0, OrderDate) >= 12 THEN 9999
ELSE DATEDIFF(mm, 0, OrderDate)
END






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
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