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


get the first date and weekday of every month in a year


get the first date and weekday of every month in a year

Author
Message
vamsikrishnacheruku
vamsikrishnacheruku
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 38
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
Wildcat
Wildcat
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1281 Visits: 1444
--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

Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42992 Visits: 19852
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 @Year char(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




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18327 Visits: 6431
There's an example in here: Calendar Tables in T-SQL that shows how to calculate the last work day of the month ("pay day"), which is not too dissimilar to your problem.


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
ScottPletcher
ScottPletcher
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20218 Visits: 7419
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) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)

Group: General Forum Members
Points: 220730 Visits: 42002
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

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)SSC Guru (220K reputation)

Group: General Forum Members
Points: 220730 Visits: 42002
@Scott,

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

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)

Group: General Forum Members
Points: 97575 Visits: 38988
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))




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
ScottPletcher
ScottPletcher
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20218 Visits: 7419
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) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)

Group: General Forum Members
Points: 97575 Visits: 38988
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?

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
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