1- IF OBJECT_ID (' dbo.uf_DateCalc' ) IS NOT NULL DROP FUNCTION dbo .uf_DateCalc
2- GO
3- -- =============================================
4- -- Author: Chad Baldwin
5- -- Create date: 2017-04-13
6- -- Description: Dates
7- -- =============================================
8- CREATE FUNCTION dbo .uf_DateCalc (
9- @SeedDate DATE ,
10- @DateCode VARCHAR (5 )
1+ CREATE OR ALTER FUNCTION dbo .uf_DateCalc (
2+ @SeedDate date = NULL ,
3+ @DateCode varchar (5 ) = NULL
114)
12- RETURNS @Return TABLE (
13- Code VARCHAR (5 ),
14- Label VARCHAR (100 ),
15- BeginDate DATETIME ,
16- EndDate DATETIME ,
17- EndOfDayDate DATETIME
5+ RETURNS @Return table (
6+ Code varchar (5 ) NOT NULL ,
7+ [Label] varchar (100 ) NOT NULL ,
8+ BeginDate datetime2 NOT NULL ,
9+ EndDateInclusiveDT datetime NOT NULL ,
10+ EndDateInclusiveDT2 datetime2 NOT NULL ,
11+ EndDateExclusive datetime2 NOT NULL
1812)
1913AS
20- BEGIN
21- SELECT @SeedDate = COALESCE (@SeedDate, GETDATE ())
22-
23- INSERT INTO @Return (Code, Label, BeginDate, EndDate, EndOfDayDate)
24- SELECT Code = x .Code
25- , Label = CONVERT (VARCHAR (100 ), x.[Period])
26- , BeginDate = CONVERT (DATETIME , x .BeginDate )
27- , EndDate = CONVERT (DATETIME , x .EndDate )
28- , EndOfDayDate = x .EndDate + CONVERT (DATETIME , ' 23:59:59.997' )
29- FROM (
30- SELECT Today = CONVERT (DATETIME , @SeedDate) -- Reporting on last complete day
31- ) t
32- CROSS APPLY (SELECT DiffYY = DATEDIFF (yy, 0 , t .Today )
33- , DiffMM = DATEDIFF (mm, 0 , t .Today )
34- , DiffWK = DATEDIFF (wk, 0 , t .Today )
35- , DiffDD = DATEDIFF (dd, 0 , t .Today )
36- , DiffQQ = DATEDIFF (qq, 0 , t .Today )
37- ) y
38- CROSS APPLY (
39- VALUES (' D' , ' Day' , t .Today , t .Today )
40- , (' M' , ' Month' , DATEADD (mm, y .DiffMM , 0 ) , DATEADD (mm, y .DiffMM + 1 , 0 ) - 1 )
41- , (' MTD' , ' Month To Date' , DATEADD (mm, y .DiffMM , 0 ) , t .Today )
42- , (' Q' , ' Quarter' , DATEADD (qq, y .DiffQQ , 0 ) , DATEADD (qq, y .DiffQQ + 1 , 0 ) - 1 )
43- , (' QTD' , ' Quarter to Date' , DATEADD (qq, y .DiffQQ , 0 ) , t .Today )
44- , (' YTD' , ' Year To Date' , DATEADD (yy, y .DiffYY , 0 ) , t .Today )
14+ BEGIN ;
15+ SELECT @SeedDate = COALESCE(@SeedDate, GETDATE());
4516
46- , (' PD' , ' Previous Day' , t .Today - 1 , t .Today - 1 )
47- , (' PW' , ' Previous Week' , DATEADD (wk, y .DiffWK - 1 , 0 ) , DATEADD (wk, y .DiffWK , 0 ) - 1 )
48- , (' PM' , ' Previous Month' , DATEADD (mm, y .DiffMM - 1 , 0 ) , DATEADD (mm, y .DiffMM , 0 ) - 1 )
49- , (' PMTD' , ' Previous Month to Date' , DATEADD (mm, y .DiffMM - 1 , 0 ) , DATEADD (mm, - 1 , t .Today ) )
50- , (' PQ' , ' Previous Quarter' , DATEADD (qq, y .DiffQQ - 1 , 0 ) , DATEADD (qq, y .DiffQQ , 0 ) - 1 )
51- , (' PQTD' , ' Previous Quarter to Date' , DATEADD (qq, y .DiffQQ - 1 , 0 ) , DATEADD (qq, - 1 , t .Today ) )
52- , (' PYQ' , ' Previous Year Quarter' , DATEADD (qq, y .DiffQQ - 4 , 0 ) , DATEADD (qq, y .DiffQQ - 3 , 0 ) - 1 )
53- , (' PYQTD' , ' Previous Year Quarter to Date' , DATEADD (qq, y .DiffQQ - 4 , 0 ) , DATEADD (yy, - 1 , t .Today ) )
54- , (' PY' , ' Previous Year' , DATEADD (yy, y .DiffYY - 1 , 0 ) , DATEADD (yy, y .DiffYY , 0 ) - 1 )
55- , (' PYTD' , ' Previous Year to Date' , DATEADD (yy, y .DiffYY - 1 , 0 ) , DATEADD (yy, - 1 , t .Today ) )
17+ WITH cte_Dates AS (
18+ SELECT DiffYY = DATEDIFF(yy, 0 , @SeedDate)
19+ , DiffMM = DATEDIFF(mm, 0 , @SeedDate)
20+ , DiffWK = DATEDIFF(wk, 0 , @SeedDate)
21+ , DiffDD = DATEDIFF(dd, 0 , @SeedDate)
22+ , DiffQQ = DATEDIFF(qq, 0 , @SeedDate)
23+ )
24+ INSERT INTO @Return (Code, [Label], BeginDate, EndDateInclusiveDT, EndDateInclusiveDT2, EndDateExclusive)
25+ SELECT Code = x .Code
26+ , [Label] = CONVERT (varchar (100 ), x.[Period])
27+ , BeginDate = CONVERT (datetime2, x .BeginDate )
28+ , EndDateInclusiveDT = DATEADD(MILLISECOND, - 3 , DATEADD(DAY, 1 , CONVERT (datetime, x .EndDate )))
29+ , EndDateInclusiveDT2 = DATEADD(NANOSECOND, - 100 , DATEADD(DAY, 1 , CONVERT (datetime2, x .EndDate ))) -- +1 day -1 tick
30+ , EndDateExclusive = DATEADD(DAY, 1 , CONVERT (datetime2, x .EndDate ))
31+ FROM cte_Dates t
32+ CROSS APPLY (
33+ VALUES (' CD' , ' Current Day' , @SeedDate , @SeedDate )
34+ , (' CM' , ' Current Month' , DATEADD(mm, t .DiffMM , 0 ) , DATEADD(dd, - 1 , DATEADD(mm, t .DiffMM + 1 , 0 )) )
35+ , (' CMTD' , ' Current Month To Date' , DATEADD(mm, t .DiffMM , 0 ) , @SeedDate )
36+ , (' CQ' , ' Current Quarter' , DATEADD(qq, t .DiffQQ , 0 ) , DATEADD(dd, - 1 , DATEADD(qq, t .DiffQQ + 1 , 0 )) )
37+ , (' CQTD' , ' Current Quarter to Date' , DATEADD(qq, t .DiffQQ , 0 ) , @SeedDate )
38+ , (' CY' , ' Current Year' , DATEADD(yy, t .DiffYY , 0 ) , DATEADD(dd, - 1 , DATEADD(yy, t .DiffYY + 1 , 0 )) )
39+ , (' CYTD' , ' Current Year To Date' , DATEADD(yy, t .DiffYY , 0 ) , @SeedDate )
5640
57- , (' L7D' , ' Last 7 days' , t .Today - ( 7 - 1 ) , t .Today )
58- , (' L14D' , ' Last 14 days' , t .Today - (14 - 1 ) , t .Today )
59- , (' L21D' , ' Last 21 days' , t .Today - (21 - 1 ) , t .Today )
60- , (' L28D' , ' Last 28 days' , t .Today - (28 - 1 ) , t .Today )
61- , (' L30D' , ' Last 30 days' , t .Today - (30 - 1 ) , t .Today )
62- , (' L60D' , ' Last 60 days' , t .Today - (60 - 1 ) , t .Today )
63- , (' L90D' , ' Last 90 days' , t .Today - (90 - 1 ) , t .Today )
41+ , (' PD' , ' Previous Day' , DATEADD(dd, - 1 , @SeedDate) , DATEADD(dd, - 1 , @SeedDate) )
42+ -- , ('PW' , 'Previous Week' , DATEADD(wk, y.DiffWK - 1, 0) , DATEADD(dd, -1, DATEADD(wk, y.DiffWK, 0)) ) -- Removed temporarily - for some reason defaults to Monday as first day of week, despite DATEFIRST setting
43+ , (' PM' , ' Previous Month' , DATEADD(mm, t .DiffMM - 1 , 0 ) , DATEADD(dd, - 1 , DATEADD(mm, t .DiffMM , 0 )) )
44+ , (' PMTD' , ' Previous Month to Date' , DATEADD(mm, t .DiffMM - 1 , 0 ) , DATEADD(mm, - 1 , @SeedDate) )
45+ , (' PQ' , ' Previous Quarter' , DATEADD(qq, t .DiffQQ - 1 , 0 ) , DATEADD(dd, - 1 , DATEADD(qq, t .DiffQQ , 0 )) )
46+ , (' PQTD' , ' Previous Quarter to Date' , DATEADD(qq, t .DiffQQ - 1 , 0 ) , DATEADD(qq, - 1 , @SeedDate) )
47+ , (' PYQ' , ' Previous Year Quarter' , DATEADD(qq, t .DiffQQ - 4 , 0 ) , DATEADD(dd, - 1 , DATEADD(qq, t .DiffQQ - 3 , 0 )) )
48+ , (' PYQTD' , ' Previous Year Quarter to Date' , DATEADD(qq, t .DiffQQ - 4 , 0 ) , DATEADD(yy, - 1 , @SeedDate) )
49+ , (' PY' , ' Previous Year' , DATEADD(yy, t .DiffYY - 1 , 0 ) , DATEADD(dd, - 1 , DATEADD(yy, t .DiffYY , 0 )) )
50+ , (' PYTD' , ' Previous Year to Date' , DATEADD(yy, t .DiffYY - 1 , 0 ) , DATEADD(yy, - 1 , @SeedDate) )
51+ ) x(Code, [Period], BeginDate, EndDate)
52+ WHERE x .Code = @DateCode OR @DateCode IS NULL
53+ UNION
54+ SELECT Code = UPPER (@DateCode)
55+ , [Label] = CONCAT_WS(' ' , CASE LEFT(@DateCode, 1 ) WHEN ' L' THEN ' Last' WHEN ' P' THEN ' Previous' ELSE NULL END, t.[Value], ' days' )
56+ , BeginDate = CONVERT (datetime2, x .BeginDate )
57+ , EndDateInclusiveDT = DATEADD(MILLISECOND, - 3 , DATEADD(DAY, 1 , CONVERT (datetime, x .EndDate )))
58+ , EndDateInclusiveDT2 = DATEADD(NANOSECOND, - 100 , DATEADD(DAY, 1 , CONVERT (datetime2, x .EndDate ))) -- +1 day -1 tick
59+ , EndDateExclusive = DATEADD(DAY, 1 , CONVERT (datetime2, x .EndDate ))
60+ FROM (
61+ SELECT [Value] = CONVERT (int , SUBSTRING (@DateCode, 2 , LEN(@DateCode)- 2 ))
62+ , Multiplier = IIF(LEFT(@DateCode, 1 ) = ' P' , 2 , 1 )
63+ ) t
64+ CROSS APPLY (
65+ SELECT BeginDate = DATEADD(DAY , - ((t.[Value] * t .Multiplier )- 1 ), @SeedDate)
66+ , EndDate = DATEADD(DAY , - (t.[Value] * (t .Multiplier - 1 )), @SeedDate)
67+ ) x
68+ WHERE @DateCode LIKE ' [LP][0-9]D'
69+ OR @DateCode LIKE ' [LP][0-9][0-9]D'
70+ OR @DateCode LIKE ' [LP][0-9][0-9][0-9]D' ;
6471
65- -- , ('L2M' , 'Last 2 months' , DATEADD(mm, y.DiffMM - 2, 0) , DATEADD(mm, y.DiffMM, 0) - 1 )
66- -- , ('L3M' , 'Last 3 months' , DATEADD(mm, y.DiffMM - 3, 0) , DATEADD(mm, y.DiffMM, 0) - 1 )
67- -- , ('L4M' , 'Last 4 months' , DATEADD(mm, y.DiffMM - 4, 0) , DATEADD(mm, y.DiffMM, 0) - 1 )
68- -- , ('L5M' , 'Last 5 months' , DATEADD(mm, y.DiffMM - 5, 0) , DATEADD(mm, y.DiffMM, 0) - 1 )
69- -- , ('L6M' , 'Last 6 months' , DATEADD(mm, y.DiffMM - 6, 0) , DATEADD(mm, y.DiffMM, 0) - 1 )
70- ) x(Code, [Period], BeginDate, EndDate)
71- WHERE x .Code = @DateCode OR @DateCode IS NULL
72-
73- RETURN
74- END
75- GO
72+ RETURN;
73+ END;
74+ GO
0 commit comments