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

get the first date and weekday of every month in a year Expand / Collapse
Author
Message
Posted Monday, March 10, 2014 11:42 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, September 24, 2014 4:38 AM
Points: 2, Visits: 34
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
Post #1549409
Posted Monday, March 10, 2014 11:57 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Tuesday, March 18, 2014 1:26 PM
Points: 405, Visits: 1,431
--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
Post #1549420
Posted Monday, March 10, 2014 12:46 PM This worked for the OP Answer marked as solution


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: Yesterday @ 8:15 PM
Points: 3,613, Visits: 8,104
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.
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?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1549439
Posted Monday, March 10, 2014 6:39 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 @ 4:09 AM
Points: 3,420, Visits: 5,344
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!
Post #1549534
Posted Friday, March 14, 2014 4:43 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 4:15 PM
Points: 2,120, Visits: 3,202
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)

Carl Sagan said: "There is no such thing as a dumb question." Sagan obviously never watched a congressional hearing!
Post #1551408
Posted Friday, March 14, 2014 5:18 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 10:33 PM
Points: 35,259, Visits: 31,740
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1551413
Posted Friday, March 14, 2014 5:44 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 10:33 PM
Points: 35,259, Visits: 31,740
@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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1551416
Posted Friday, March 14, 2014 10:05 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 11:08 PM
Points: 20,696, Visits: 32,330
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))





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)
Post #1551433
Posted Friday, March 14, 2014 10:34 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 4:15 PM
Points: 2,120, Visits: 3,202
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)

Carl Sagan said: "There is no such thing as a dumb question." Sagan obviously never watched a congressional hearing!
Post #1551440
Posted Friday, March 14, 2014 11:38 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 11:08 PM
Points: 20,696, Visits: 32,330
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?



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)
Post #1551446
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse