Date Manipulation
Dates can be manipulated in a way to identify future days of the week, monthly intervals and weekly intervals. The example below shows some of the exotic ways in which dates can be encoded by doing arithmetic on the date values. DateAdd and DateSerial Are powerful tools for computing dates.
Program Code
Option Explicit
Option Base 1
Public Sub SetUpMonths()
' *********************************************************
' Results of the Date Calculations
' *********************************************************
'Jun 202006 6 2020 06 2020
'Jul 202007 7 2020 07 2020
'Aug 202008 8 2020 08 2020
'Sep 202009 9 2020 09 2020
'Oct 202010 10 2020 10 2020
'Nov 202011 11 2020 11 2020
'Dec 202012 12 2020 12 2020
'Jan 202101 1 2021 01 2021
'Feb 202102 2 2021 02 2021
'Mar 202103 3 2021 03 2021
'Apr 202104 4 2021 04 2021
'May 202105 5 2021 05 2021
Dim dteCurrentDate As Date
Dim lngCurrentMonth As Long
Dim strMonthTitles(12) As String
Dim lngMonthNumber(12) As Long
Dim strMonthString(12) As String
Dim lngYearNumber(12) As Long
Dim strYearString(12) As String
Dim strYearMonth(12) As String
Dim i As Long
Dim j As Long
strMonthTitles(1) = "Jan"
strMonthTitles(2) = "Feb"
strMonthTitles(3) = "Mar"
strMonthTitles(4) = "Apr"
strMonthTitles(5) = "May"
strMonthTitles(6) = "Jun"
strMonthTitles(7) = "Jul"
strMonthTitles(8) = "Aug"
strMonthTitles(9) = "Sep"
strMonthTitles(10) = "Oct"
strMonthTitles(11) = "Nov"
strMonthTitles(12) = "Dec"
dteCurrentDate = Date
j = 0
For i = -11 To 0
j = j + 1
strYearMonth(j) = Format(Year(DateAdd("m", i, dteCurrentDate)), "0000") & Format(Month(DateAdd("m", i, dteCurrentDate)), "00")
lngMonthNumber(j) = Month(DateAdd("m", i, dteCurrentDate))
lngCurrentMonth = Month(DateAdd("m", i, dteCurrentDate))
lngYearNumber(j) = Year(DateAdd("m", i, dteCurrentDate))
strMonthString(j) = Format(Month(DateAdd("m", i, dteCurrentDate)), "00")
strYearString(j) = Format(Year(DateAdd("m", i, dteCurrentDate)), "0000")
Debug.Print (strMonthTitles(lngCurrentMonth) & " " & strYearMonth(j) & " " & lngMonthNumber(j) & " " & lngYearNumber(j) & " " & strMonthString(j) & " " & strYearString(j))
Next i
End Sub
' **********************************************************************************
' Next Example
' **********************************************************************************
Option Explicit
Option Base 1
Public Function TestDateManipulation()
Dim dteRunDate As Date
Dim intStartingMonth As Integer
Dim intStartingYear As Integer
Dim intEndingMonth As Integer
Dim intEndingYear As Integer
Dim i As Integer
Dim intColumnHeader As Integer
Dim dteStartingMonday As Date
Dim dteNextMonday As Date
Dim intHeaderColumn As Integer
Dim strL3EndingYYYYWW As String
Dim strL3StartingYYYYWW As String
Dim dteMondayLastYear As Date
Dim dteMondayLastYearPlus18Weeks As Date
Dim strN4StartingYYYYWW As String
Dim strN4EndingYYYYWW As String
Dim dteMonday(14) As Date
Dim strYearWeek(14) As String
Dim strPO14WeeksOutStartYYYYWW As String
Dim strPO14WeeksOutEndingYYYYWW As String
' ********************************************************
' Calculate a 12 Month Interval Moving Back From Today
' ********************************************************
dteRunDate = Cells(1, 1).Value
intStartingMonth = Month(DateSerial(Year(dteRunDate), Month(dteRunDate) - 11, 1))
intStartingYear = Year(DateSerial(Year(dteRunDate), Month(dteRunDate) - 11, 1))
intEndingMonth = Month(dteRunDate)
intEndingYear = Year(dteRunDate)
' ********************************************************
' Translate 1 - 12 into Jan - Dec
' ********************************************************
intHeaderColumn = 1
For i = 1 To 12
intHeaderColumn = intHeaderColumn + 1
Cells(1, intHeaderColumn).Value = Format(DateSerial(2000, i, 1), "mmm")
Next i
' ********************************************************
' Other Exotic Examples Of Date Manipulation
' ********************************************************
dteStartingMonday = GetMondayForStartingWeek()
dteNextMonday = dteStartingMonday
strL3EndingYYYYWW = GetYearWeekOfDate(dteStartingMonday - 2)
strL3StartingYYYYWW = GetYearWeekOfDate(dteStartingMonday - 79)
dteMondayLastYear = DateSerial(Year(dteStartingMonday) - 1, Month(dteStartingMonday), Day(dteStartingMonday))
dteMondayLastYearPlus18Weeks = dteMondayLastYear + 125
strN4StartingYYYYWW = GetYearWeekOfDate(dteMondayLastYear)
strN4EndingYYYYWW = GetYearWeekOfDate(dteMondayLastYearPlus18Weeks)
' ***********************************************************************
' Continue With Setting Up The Date Array
' ***********************************************************************
For i = 1 To 14
dteMonday(i) = dteNextMonday
strYearWeek(i) = GetYearWeekOfDate(dteNextMonday)
dteNextMonday = dteNextMonday + 7
Next i
' ***********************************************************************
' Capture PO Values for 90 Days After Week 14
' ***********************************************************************
strPO14WeeksOutStartYYYYWW = GetYearWeekOfDate(dteMonday(14) + 7)
strPO14WeeksOutEndingYYYYWW = GetYearWeekOfDate(dteMonday(14) + 84)
End Function
' ********************************************************
' Get The Monday Date Given Today's Date
' ********************************************************
Public Function GetMondayForStartingWeek() As Date
' ********************************************************
' Sunday Starts A New Week
' ********************************************************
' Using Todays Date, This will Return the Monday of the Starting Week
Dim intStartWeek As Integer
Dim intStartYear As Integer
Dim dteStartMonday As Date
intStartWeek = Format(Date, "ww")
intStartYear = Format(Date, "yyyy")
dteStartMonday = WeekStart(intStartWeek, intStartYear)
GetMondayForStartingWeek = dteStartMonday
End Function
' ********************************************************
' Convert A Date into YYYYWW Format
' ********************************************************
Public Function GetYearWeekOfDate(dteInputDate As Date) As String
' Using The Date Passed, Get the YYYYWW of the date
Dim intStartWeek As Integer
Dim intStartYear As Integer
Dim strStartYearWeek As String
intStartWeek = Format(dteInputDate, "ww")
intStartYear = Format(dteInputDate, "yyyy")
strStartYearWeek = intStartYear & Format(intStartWeek, "0#")
GetYearWeekOfDate = strStartYearWeek
End Function
' ********************************************************
' Get The Start of the Week Date Given Week # & Year
' ********************************************************
Public Function WeekStart(WhichWeek As Integer, WhichYear As _
Integer) As Date
WeekStart = YearStart(WhichYear) + ((WhichWeek - 1) * 7)
End Function
' ********************************************************
'
' ********************************************************
Public Function YearStart(WhichYear As Integer) As Date
' ************************************************
' Compute the Date of the First Monday of the Year
' ************************************************
Dim WeekDay As Integer
Dim NewYear As Date
NewYear = DateSerial(WhichYear, 1, 1)
' ************************************************
' The Mod 7 Of A Saturday Is Zero, So To Have
' Monday Be an index of zero, subtract 2
' ************************************************
WeekDay = (NewYear - 2) Mod 7 'Generate weekday index where Monday = 0
If WeekDay < 4 Then
YearStart = NewYear - WeekDay
Else
YearStart = NewYear - WeekDay + 7
End If
End Function