To count dates that fall between a date range we can use SUMPRODUCT
with a twist. Suppose you have a list of valid dates in A1:A20. The formula we
can use to count dates that fall between 2 dates is;
=SUMPRODUCT(($A$1:$A$20>D1)*($A$1:$A$20<E1))
Where D1 houses your start date and E1 you end date.
Or, we can hard code the dates into our SUMPRODUCT Function by using the DATE
Function.
=SUMPRODUCT(($A$1:$A$20>DATE(2010,7,29))*($A$1:$A$20<DATE(2010,8,1)))
Syntax for the date function is: DATE(Year, Month, Day)
Let's take this a step further and sum up numbers in Column "B"
that correspond to our date range.
=SUMPRODUCT(($A$1:$A$20>DATE(2010,7,29))*($A$1:$A$20<DATE(2010,8,1))*($B$1:$B$20))
We can even add another condition to numbers in Column B. Say we only want to
sum numbers, in range B1:20, that are greater than 3. We would use;
=SUMPRODUCT(($A$1:$A$20>DATE(2010,7,29))*($A$1:$A$20<DATE(2010,8,1))*($B$1:$B$20>3)*($B$1:$B$20))
Here's how to create relatively easy Date Adder by using a UserForm, 3 TextBox Controls, 5 Label Controls, 1 ComboBox Control and 1 CommandButton Control.
- TextBox1 = Start Date
- TextBox2 = Positive/Negative Amount
- ComboBox1 = Period. I.e Days, Weeks, Months, Year
- CommandButton1 = Add/Take\
- Label1 = Result
CODE
Dim strPeriod As String Private Sub ComboBox1_Change() If ComboBox1.ListIndex = -1 Then MsgBox "Invalid period", vbCritical ComboBox1.SetFocus Exit Sub End If With ComboBox1 If .ListIndex = 0 Then strPeriod = "D" If .ListIndex = 1 Then strPeriod = "WW" If .ListIndex = 2 Then strPeriod = "M" If .ListIndex = 3 Then strPeriod = "YYYY" End With End Sub Private Sub CommandButton1_Click() If Not IsDate(TextBox1) Then MsgBox "Non valid date", vbCritical TextBox1 = vbNullString TextBox1.SetFocus Exit Sub End If If Not IsNumeric(TextBox2) Then MsgBox "Invalid amount", vbCritical TextBox2 = vbNullString TextBox2.SetFocus Exit Sub End If If ComboBox1.ListIndex = -1 Then MsgBox "Invalid period", vbCritical ComboBox1.SetFocus Exit Sub End If Label1 = Format(DateAdd(strPeriod, TextBox2, TextBox1), "dddd dd mmm yyyy") End Sub Private Sub TextBox1_Exit(ByVal Cancel As MSForms.ReturnBoolean) If TextBox1 = vbNullString Then Exit Sub If Not IsDate(TextBox1) Then MsgBox "Non valid date", vbCritical TextBox1 = vbNullString Cancel = True End If End Sub Private Sub UserForm_Initialize() ComboBox1.List = Split("Day,Week,Month,Year", ",") End Sub
Excel Dashboard Reports & Excel Dashboard Charts 50% Off
Become an ExcelUser Affiliate & Earn Money
Microsoft � and Microsoft Excel � are registered trademarks of Microsoft Corporation. OzGrid is in no way associated with Microsoft