March 10, 2014 at 11:42 am
hai i want to get the first date and weekday of every month in a year .
1/jan/2014, monday
1/feb/2014,thrusday
, ,
,,
,,
,,,
,,,
,,
1/nov/2014, thrusday
1/dec/2014, friday
like this output should be
March 10, 2014 at 11:57 am
--First Day of this Month
select DATEADD(mm, DATEDIFF(mm,0,getdate()), 0)
vamsikrishnacheruku (3/10/2014)
hai i want to get the first date and weekday of every month in a year .1/jan/2014, monday
1/feb/2014,thrusday
, ,
,,
,,
,,,
,,,
,,
1/nov/2014, thrusday
1/dec/2014, friday
like this output should be
March 10, 2014 at 12:46 pm
The best option could be a calendar table that can establish those values without further calculations.
If you don't have it, or can't create it, here's a possible option. Be sure to understand it and ask any questions you have before implementing it. It uses a Tally (or numbers) table in the form of a CTE. Understanding this concepts might help a lot (for this problem and many others).
DECLARE @Yearchar(4) = '2014';
WITH E1 AS(
SELECT N FROM (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) E(N)
),
E3 AS(
SELECT a.N FROM E1 a, E1 b, E1 c
),
cteTally AS(
SELECT TOP (360) DATEADD( dd, (ROW_NUMBER() OVER( ORDER BY (SELECT NULL)) - 1), CAST(@Year AS date)) myDate
FROM E3
),
weekDays AS(
SELECT myDate, ROW_NUMBER() OVER(PARTITION BY MONTH(myDate) ORDER BY myDate) rn
FROM cteTally
WHERE DATENAME( WEEKDAY, myDate) NOT IN ('Saturday', 'Sunday')
)
SELECT myDate FirstWeekDay,
DATEADD(MM, DATEDIFF(MM, 0, myDate), 0) FirstDay
FROM weekDays
WHERE rn = 1
March 10, 2014 at 6:39 pm
There's an example in here: Calendar Tables in T-SQL[/url] that shows how to calculate the last work day of the month ("pay day"), which is not too dissimilar to your problem.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
March 14, 2014 at 4:43 pm
Not a big deal in this case, but I don't like generating hundreds of values when I need only 12 :-). I think code below does less work and also has no language dependencies:
DECLARE @year datetime
SET @year = GETDATE()
;WITH
cteDigits AS (
SELECT 0 AS digit UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4 UNION ALL
SELECT 5 UNION ALL SELECT 6 UNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9
),
cteMonths AS (
SELECT [10s].digit * 10 + [1s].digit AS month#
FROM cteDigits [1s]
CROSS JOIN cteDigits [10s]
WHERE
[10s].digit * 10 + [1s].digit BETWEEN 1 AND 12
)
SELECT
first_day_of_month +
CASE WHEN DATEDIFF(DAY, 0, first_day_of_month) % 7 < 5 THEN 0
WHEN DATEDIFF(DAY, 0, first_day_of_month) % 7 = 5 THEN 2 ELSE 1 END
AS first_workday_of_month
FROM cteMonths
CROSS APPLY (
SELECT DATEADD(YEAR, DATEDIFF(YEAR, 0, @year), 0) AS first_day_of_year
) AS ca1
CROSS APPLY (
SELECT DATEADD(MONTH, month# - 1, first_day_of_year) AS first_day_of_month
) AS ca2
ORDER BY
first_workday_of_month
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
March 14, 2014 at 5:18 pm
I originally missed what Scott was talking about and had to edit this post. Like he said, no biggee on this one but I agree... seems like there's a lot of rows being generated to support this task.
Shifting gears, I know the OP only asked for 1 year but I'd also write it to handle more than one year so I wouldn't have to run the code more than once.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 14, 2014 at 5:44 pm
I really like this line of clever code...
WHEN DATEDIFF(DAY, 0, first_day_of_month) % 7 = 5 THEN 2 ELSE 1 END
--Jeff Moden
Change is inevitable... Change for the better is not.
March 14, 2014 at 10:05 pm
vamsikrishnacheruku (3/10/2014)
hai i want to get the first date and weekday of every month in a year .1/jan/2014, monday
1/feb/2014,thrusday
, ,
,,
,,
,,,
,,,
,,
1/nov/2014, thrusday
1/dec/2014, friday
like this output should be
Can someone explain to me the weekdays? From what is posted above, it doesn't make any sense.
I ask because if you want the First of each month and the day it falls on, I cam up with this. Sorry Jeff, only coded it for a single year.
declare @Year date = getdate();
with TwelveCount(n) as (select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12))dt(n))
select
dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0)) FirstOfMonth,
datename(dw,dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0))) NameOfDay
from
TwelveCount
order by
dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0))
March 14, 2014 at 10:34 pm
Lynn Pettis (3/14/2014)
vamsikrishnacheruku (3/10/2014)
hai i want to get the first date and weekday of every month in a year .1/jan/2014, monday
1/feb/2014,thrusday
, ,
,,
,,
,,,
,,,
,,
1/nov/2014, thrusday
1/dec/2014, friday
like this output should be
Can someone explain to me the weekdays? From what is posted above, it doesn't make any sense.
I ask because if you want the First of each month and the day it falls on, I cam up with this. Sorry Jeff, only coded it for a single year.
declare @Year date = getdate();
with TwelveCount(n) as (select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12))dt(n))
select
dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0)) FirstOfMonth,
datename(dw,dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0))) NameOfDay
from
TwelveCount
order by
dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0))
I took it as meaning the first day of the month that does not fall on a Saturday or a Sunday, i.e., that is a "weekday", not a weekend-day.
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
March 14, 2014 at 11:38 pm
ScottPletcher (3/14/2014)
Lynn Pettis (3/14/2014)
vamsikrishnacheruku (3/10/2014)
hai i want to get the first date and weekday of every month in a year .1/jan/2014, monday
1/feb/2014,thrusday
, ,
,,
,,
,,,
,,,
,,
1/nov/2014, thrusday
1/dec/2014, friday
like this output should be
Can someone explain to me the weekdays? From what is posted above, it doesn't make any sense.
I ask because if you want the First of each month and the day it falls on, I cam up with this. Sorry Jeff, only coded it for a single year.
declare @Year date = getdate();
with TwelveCount(n) as (select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12))dt(n))
select
dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0)) FirstOfMonth,
datename(dw,dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0))) NameOfDay
from
TwelveCount
order by
dateadd(month,n - 1, dateadd(year,datediff(year,0,@Year),0))
I took it as meaning the first day of the month that does not fall on a Saturday or a Sunday, i.e., that is a "weekday", not a weekend-day.
Okay, but 2014-01-01 falls on a Wednesday so how do you get Monday?
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply