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


Need the First Tuesday Beyond Y days after X Date


Need the First Tuesday Beyond Y days after X Date

Author
Message
webcudgel
webcudgel
SSC-Addicted
SSC-Addicted (400 reputation)SSC-Addicted (400 reputation)SSC-Addicted (400 reputation)SSC-Addicted (400 reputation)SSC-Addicted (400 reputation)SSC-Addicted (400 reputation)SSC-Addicted (400 reputation)SSC-Addicted (400 reputation)

Group: General Forum Members
Points: 400 Visits: 85
Comments posted to this topic are about the item Need the First Tuesday Beyond Y days after X Date
Usman Butt
Usman Butt
SSC-Addicted
SSC-Addicted (494 reputation)SSC-Addicted (494 reputation)SSC-Addicted (494 reputation)SSC-Addicted (494 reputation)SSC-Addicted (494 reputation)SSC-Addicted (494 reputation)SSC-Addicted (494 reputation)SSC-Addicted (494 reputation)

Group: General Forum Members
Points: 494 Visits: 820
Hi,

Just sorted out after some hindrance that the parentheses are not in the right order for the supplied script (last line). Below is the changed script. Cheers.

DECLARE @StartDate date
DECLARE @DaysOut tinyint
DECLARE @DesiredDayOfWeek tinyint
SET @StartDate = '20110813' --The starting date
SET @DaysOut = 4 --Number of days to count out (the Desired day is AFTER this count)
SET @DesiredDayOfWeek = 6 --The desired day of week

SELECT DATEADD( d,( @DaysOut +( 7 - ( ( 7 + DATEPART( weekday, DATEADD( d, @DaysOut, @StartDate )) - @DesiredDayOfWeek ) % 7) )), @StartDate )
Bob-683340
Bob-683340
Valued Member
Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)

Group: General Forum Members
Points: 53 Visits: 255
So which is really better - the very clever one-liner whose logic can't be unravelled without some head scratching, or the somewhat longer version that's simple enough to be self-explanatory?

select @TargetDate = dateadd(dd,@DaysOut,@StartDate)

while datepart(dw,@TargetDate) <> @DesiredDayOfWeek
set @TargetDate = @TargetDate + 1

Mike Is Here
Mike Is Here
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1486 Visits: 513
Bob-683340 (10/13/2011)
So which is really better - the very clever one-liner whose logic can't be unravelled without some head scratching, or the somewhat longer version that's simple enough to be self-explanatory?

select @TargetDate = dateadd(dd,@DaysOut,@StartDate)

while datepart(dw,@TargetDate) <> @DesiredDayOfWeek
set @TargetDate = @TargetDate + 1




I would say the one that runs faster. You can always comment around your cleverness
Jack Corbett
  Jack Corbett
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12798 Visits: 14863
First of all, this is a good article that explains how to solve a problem. There is one issue with the solution though. It works for the language setting of US English or any that has Sunday as the first day of the week. If you are in a different language setting the calculation does not work. Try this:


/* 20111009 is a Sunday */
SET LANGUAGE us_english ;

SELECT
@@LANGUAGE AS language_setting,
DATEPART(weekday, '20111009') AS weekday_number,
DATENAME(weekday, '20111009') AS weekday_name;

DECLARE @StartDate DATE
DECLARE @DaysOut TINYINT
DECLARE @DesiredDayOfWeek TINYINT
SET @StartDate = '20111009'
--The starting date
SET @DaysOut = 4
--Number of days to count out (the Desired day is AFTER this count)
SET @DesiredDayOfWeek = 6
--The desired day of week

SELECT
DATEADD(d,
(@DaysOut + (7 - (7 + DATEPART(weekday,
DATEADD(d, @DaysOut, @StartDate)) -
@DesiredDayOfWeek)) % 7), @StartDate)

Go
SET LANGUAGE italian

SELECT
@@LANGUAGE AS language_setting,
DATEPART(weekday, '20111009') AS weekday_number,
DATENAME(weekday, '20111009') AS weekday_name;

DECLARE @StartDate DATE
DECLARE @DaysOut TINYINT
DECLARE @DesiredDayOfWeek TINYINT
SET @StartDate = '20111009'
--The starting date
SET @DaysOut = 4
--Number of days to count out (the Desired day is AFTER this count)
SET @DesiredDayOfWeek = 6
--The desired day of week

SELECT
DATEADD(d,
(@DaysOut + (7 - (7 + DATEPART(weekday,
DATEADD(d, @DaysOut, @StartDate)) -
@DesiredDayOfWeek)) % 7), @StartDate)



The first results in 2011-10-14 and the second results in 2011-10-15



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
ron.mcdowell
ron.mcdowell
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 706
No matter what, SQL makes my head itch. So no matter what, I comment...comment..comment.

Thanks Itzik Ben-Gan for the in-line number generator, and tally table crusader Mr. Moden for getting N through my thick itchy skull.


DECLARE @StartDate date
DECLARE @DaysOut tinyint
DECLARE @DesiredDayOfWeek tinyint
DECLARE @TargetDate date
DECLARE @MaxDays int

SET @StartDate = '20111013' --The starting date
SET @DaysOut = 1 --Number of days to count out (the Desired day is AFTER this count)
SET @DesiredDayOfWeek = 6 --The desired day of week
SET @TargetDate = dateadd(dd,@DaysOut,@StartDate)
SET @MaxDays = @DaysOut + @DesiredDayOfWeek + 1 --Tally Table row count limiter

;WITH
L0 AS(SELECT 1 AS c UNION ALL SELECT 1),
L1 AS(SELECT 1 AS c FROM L0 AS A CROSS JOIN L0 AS B),
L2 AS(SELECT 1 AS c FROM L1 AS A CROSS JOIN L1 AS B),
L3 AS(SELECT 1 AS c FROM L2 AS A CROSS JOIN L2 AS B),
L4 AS(SELECT 1 AS c FROM L3 AS A CROSS JOIN L3 AS B),
L5 AS(SELECT 1 AS c FROM L4 AS A CROSS JOIN L4 AS B),
Nums AS(SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS N FROM L5)
SELECT TOP(1) @TargetDate = dateadd(dd,Tally_Table.N,@TargetDate)
FROM (SELECT TOP(@MaxDays) N FROM Nums ORDER BY N) AS Tally_Table
WHERE datepart(dw,dateadd(dd,Tally_Table.N,@TargetDate)) = @DesiredDayOfWeek

SELECT @TargetDate


Jack Corbett
  Jack Corbett
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12798 Visits: 14863
ron.mcdowell (10/13/2011)
No matter what, SQL makes my head itch. So no matter what, I comment...comment..comment.

Thanks Itzik Ben-Gan for the in-line number generator, and tally table crusader Mr. Moden for getting N through my thick itchy skull.


DECLARE @StartDate date
DECLARE @DaysOut tinyint
DECLARE @DesiredDayOfWeek tinyint
DECLARE @TargetDate date
DECLARE @MaxDays int

SET @StartDate = '20111013' --The starting date
SET @DaysOut = 1 --Number of days to count out (the Desired day is AFTER this count)
SET @DesiredDayOfWeek = 6 --The desired day of week
SET @TargetDate = dateadd(dd,@DaysOut,@StartDate)
SET @MaxDays = @DaysOut + @DesiredDayOfWeek + 1 --Tally Table row count limiter

;WITH
L0 AS(SELECT 1 AS c UNION ALL SELECT 1),
L1 AS(SELECT 1 AS c FROM L0 AS A CROSS JOIN L0 AS B),
L2 AS(SELECT 1 AS c FROM L1 AS A CROSS JOIN L1 AS B),
L3 AS(SELECT 1 AS c FROM L2 AS A CROSS JOIN L2 AS B),
L4 AS(SELECT 1 AS c FROM L3 AS A CROSS JOIN L3 AS B),
L5 AS(SELECT 1 AS c FROM L4 AS A CROSS JOIN L4 AS B),
Nums AS(SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS N FROM L5)
SELECT TOP(1) @TargetDate = dateadd(dd,Tally_Table.N,@TargetDate)
FROM (SELECT TOP(@MaxDays) N FROM Nums ORDER BY N) AS Tally_Table
WHERE datepart(dw,dateadd(dd,Tally_Table.N,@TargetDate)) = @DesiredDayOfWeek

SELECT @TargetDate



I like this solution, but you need to make sure you set @DesiredDayOfWeek to match the language settings in order to get the correct result, so you need to know that setting when making that choice. If you run this code with SET LANGUAGE us_english you get 2011-10-21, but if you change the language to Italian you get 2011-10-15. I think you want the first in all cases, but you need to make sure you know the language.

I have an older blog post, http://wiseman-wiseguy.blogspot.com/2008/12/simple-but-effective-code-example.html that may give someone an idea on how to make either set of code to be work with any language setting.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
SQLRNNR
SQLRNNR
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23533 Visits: 18271
Good article and good solution.

Thanks to Jack et al for providing more options/solutions.



Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

ron.mcdowell
ron.mcdowell
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 706
Here you go, Jack. Thanks for making me dig.


--SET LANGUAGE italian
--SET LANGUAGE us_english

DECLARE @StartDate date
DECLARE @DaysOut tinyint
DECLARE @DesiredDayOfWeek tinyint
DECLARE @TargetDate date
DECLARE @MaxDays int

SET @StartDate = '20111013' --The starting date
SET @DaysOut = 1 --Number of days to count out (the Desired day is AFTER this count)
SET @DesiredDayOfWeek = 6 --The desired day of week
SET @TargetDate = dateadd(dd,@DaysOut,@StartDate)
SET @MaxDays = @DaysOut + @DesiredDayOfWeek + 1 --Tally Table row count limiter

-- For @@DATEFIRST explanation: See http://www.sqlservercentral.com/articles/DateFirst/69203/ (Thanks Divya Agrawal!)
-- For Tally Table explanation: See http://www.sqlservercentral.com/articles/T-SQL/62867/ (Thanks Jeff Moden!)

;WITH
L0 AS(SELECT 1 AS c UNION ALL SELECT 1),
L1 AS(SELECT 1 AS c FROM L0 AS A CROSS JOIN L0 AS B),
L2 AS(SELECT 1 AS c FROM L1 AS A CROSS JOIN L1 AS B),
L3 AS(SELECT 1 AS c FROM L2 AS A CROSS JOIN L2 AS B),
L4 AS(SELECT 1 AS c FROM L3 AS A CROSS JOIN L3 AS B),
L5 AS(SELECT 1 AS c FROM L4 AS A CROSS JOIN L4 AS B),
Nums AS(SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS N FROM L5)
SELECT TOP(1) @TargetDate = dateadd(dd,Tally_Table.N,@TargetDate)
FROM (SELECT TOP(@MaxDays) N FROM Nums ORDER BY N) AS Tally_Table
WHERE (datepart(dw,dateadd(dd,Tally_Table.N,@TargetDate)) + @@DATEFIRST) % 7 = @DesiredDayOfWeek

SELECT @TargetDate


Jack Corbett
  Jack Corbett
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12798 Visits: 14863
ron.mcdowell (10/13/2011)
Here you go, Jack. Thanks for making me dig.


--SET LANGUAGE italian
--SET LANGUAGE us_english

DECLARE @StartDate date
DECLARE @DaysOut tinyint
DECLARE @DesiredDayOfWeek tinyint
DECLARE @TargetDate date
DECLARE @MaxDays int

SET @StartDate = '20111013' --The starting date
SET @DaysOut = 1 --Number of days to count out (the Desired day is AFTER this count)
SET @DesiredDayOfWeek = 6 --The desired day of week
SET @TargetDate = dateadd(dd,@DaysOut,@StartDate)
SET @MaxDays = @DaysOut + @DesiredDayOfWeek + 1 --Tally Table row count limiter

-- For @@DATEFIRST explanation: See http://www.sqlservercentral.com/articles/DateFirst/69203/ (Thanks Divya Agrawal!)
-- For Tally Table explanation: See http://www.sqlservercentral.com/articles/T-SQL/62867/ (Thanks Jeff Moden!)

;WITH
L0 AS(SELECT 1 AS c UNION ALL SELECT 1),
L1 AS(SELECT 1 AS c FROM L0 AS A CROSS JOIN L0 AS B),
L2 AS(SELECT 1 AS c FROM L1 AS A CROSS JOIN L1 AS B),
L3 AS(SELECT 1 AS c FROM L2 AS A CROSS JOIN L2 AS B),
L4 AS(SELECT 1 AS c FROM L3 AS A CROSS JOIN L3 AS B),
L5 AS(SELECT 1 AS c FROM L4 AS A CROSS JOIN L4 AS B),
Nums AS(SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS N FROM L5)
SELECT TOP(1) @TargetDate = dateadd(dd,Tally_Table.N,@TargetDate)
FROM (SELECT TOP(@MaxDays) N FROM Nums ORDER BY N) AS Tally_Table
WHERE (datepart(dw,dateadd(dd,Tally_Table.N,@TargetDate)) + @@DATEFIRST) % 7 = @DesiredDayOfWeek

SELECT @TargetDate



I knew someone would come up with a language neutral solution. Good work, Ron!



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
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