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


Date Upto 28 days ahead, no weekends


Date Upto 28 days ahead, no weekends

Author
Message
ringovski
ringovski
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3140 Visits: 598
Hi All,
I have a statement returning data from today up to 28 days ahead, but it is including weekends. I only want business days, how do I achieve this ?

select [MFLITM],[MFMCU]

,CASE WHEN SUM([MFUORG]) > 0

THEN SUM([MFUORG]) END as [Forecast]

FROM [dbo].[OOS_Asia_Forecast]

WHERE Normal_Date >=DATEADD(day, DATEDIFF(day,0,GETDATE()),0)

AND Normal_Date <= DATEADD(day, DATEDIFF(day,0,GETDATE())+28,0)

GROUP BY [MFLITM],[MFMCU]



Thanks for any assistance.

Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)

Group: General Forum Members
Points: 180696 Visits: 24712
This query filters out the weekends
Cool



USE TEEST;
GO
SET NOCOUNT ON;

DECLARE @SAMPLE_SIZE INT = 100;
;WITH T(N) AS (SELECT X.N FROM (VALUES (0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) X(N))
, NUMS(N) AS (SELECT TOP(@SAMPLE_SIZE) ROW_NUMBER() OVER (ORDER BY @@VERSION) AS N
FROM T T1,T T2,T T3)
,SAMPLE_DATA AS
(
SELECT
NM.N AS SD_RID
,DATEADD(DAY,NM.N,GETDATE() - 15) AS SD_DATE
,1 + (ABS(CHECKSUM(NEWID())) % 3 ) AS SD_GROUP
,ABS(CHECKSUM(NEWID())) % 1000 AS SD_VALUE
FROM NUMS NM
)
SELECT
SD.SD_GROUP
,SUM(SD.SD_VALUE) AS [Forecast]
--,SD.SD_RID
--,SD.SD_DATE
FROM SAMPLE_DATA SD
WHERE SD.SD_DATE >= CONVERT(DATE,GETDATE(),0)
AND SD.SD_DATE < CONVERT(DATE,GETDATE() + 29,0)
AND (DATEDIFF(DAY,0,SD.SD_DATE) % 7) < 5
GROUP BY SD.SD_GROUP;

ringovski
ringovski
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3140 Visits: 598
Thanks for the reply, but how do i apply your cte's to my statement?
Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)

Group: General Forum Members
Points: 180696 Visits: 24712
ringovski - Friday, May 4, 2018 4:45 PM
Thanks for the reply, but how do i apply your cte's to my statement?

The CTE is only there to provide sample data, it is the WHERE clause that does the trick.
Cool



WHERE SD.SD_DATE >= CONVERT(DATE,GETDATE(),0)
AND SD.SD_DATE < CONVERT(DATE,GETDATE() + 29,0)
AND (DATEDIFF(DAY,0,SD.SD_DATE) % 7) < 5


ringovski
ringovski
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3140 Visits: 598
Thanks a lot for the script. Can you explain the logic behind it so i can understand it?
Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)

Group: General Forum Members
Points: 180696 Visits: 24712
ringovski - Saturday, May 5, 2018 3:34 AM
Thanks a lot for the script. Can you explain the logic behind it so i can understand it?

The logic for the weekdays is that date 0 is a Monday, modulus 7 of the number of dates from date 0 will return 5 for Saturdays and 6 for Sundays, hence limit the results to the set where that number is lower than 5 will return working (non weekend) days.
The conversion of getdate to a date removes the time part which simplifies the temporal framing of the query and adding 29 days allows us to use less than rather than less or equal to, slightly better performance.
Cool

Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (983K reputation)SSC Guru (983K reputation)SSC Guru (983K reputation)SSC Guru (983K reputation)SSC Guru (983K reputation)SSC Guru (983K reputation)SSC Guru (983K reputation)SSC Guru (983K reputation)

Group: General Forum Members
Points: 983249 Visits: 49366
Eirikur Eiriksson - Saturday, May 5, 2018 3:47 AM
ringovski - Saturday, May 5, 2018 3:34 AM
Thanks a lot for the script. Can you explain the logic behind it so i can understand it?

The logic for the weekdays is that date 0 is a Monday, modulus 7 of the number of dates from date 0 will return 5 for Saturdays and 6 for Sundays, hence limit the results to the set where that number is lower than 5 will return working (non weekend) days.
The conversion of getdate to a date removes the time part which simplifies the temporal framing of the query and adding 29 days allows us to use less than rather than less or equal to, slightly better performance.
Cool


This part of Eirikur's code replaces a WHILE Loop Counter using the "Pseudo Cursor" behind every SELECT to produce a sequence of numbers. The sample size variable limits its scope.


DECLARE @SAMPLE_SIZE INT = 100;
;WITH T(N) AS (SELECT X.N FROM (VALUES (0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) X(N))
, NUMS(N) AS (SELECT TOP(@SAMPLE_SIZE) ROW_NUMBER() OVER (ORDER BY @@VERSION) AS N
FROM T T1,T T2,T T3)

To learn more about this powerful tool that is used as a bit of a high performance "Swiss Army Knife of SQL", please see the following article. Eirikur is using the "Cascading CTE" method that was (to the best of my knowledge), first published by Itzik Ben-Gan.
The "Numbers" or "Tally" Table: What it is and how it replaces a loop

The reason why he generates the dates instead of the dates available in the original table is to cover the eventuality of having a weekday date with no entries, which should be reported as having a "zero sum".

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

When you put the right degree of spin on it, the number 318 is also a glyph that describes the nature of a DBAs job. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Sergiy
Sergiy
SSC Guru
SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)

Group: General Forum Members
Points: 108559 Visits: 14460
Do you need "business days" or "week days"?

There are public holidays which are not business days, and might not fall on weekends.
ringovski
ringovski
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3140 Visits: 598
mmm good point, didn't think of that not sure I will find out tomorrow.
Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)SSC Guru (180K reputation)

Group: General Forum Members
Points: 180696 Visits: 24712
If you need to include holidays on top of the weekends, you will need to incorporate a calendar table.
Cool
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