Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Limiting Entry of Prior Dates.
Written by Allen Wyatt (last updated May 2, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
If you use the data validation capabilities of Excel, you can limit what goes into a cell, based on the contents of another cell. For instance, you can easily limit what goes into cell A2 based on a date that is in cell A1. Follow these steps:
Figure 1. The Settings tab of the Data Validation dialog box.
Now, anytime you try to enter a date in cell A2 that is earlier than the date in cell A1, Excel displays an error message and will not allow the date to be entered.
What happens, however, when you want to limit the dates that can be entered in cell A1? For instance, if you put the date 4/1/20 in cell A1, and you want to make sure that the next date entered in A1 is not earlier than 4/1/20. If you put a date such as 4/15/20 in cell A1, that would be OK, but then the next time you enter a date in cell A1 you don't want it earlier than 4/15/20. In other words, you want to make sure that cell A1 can only accept dates later than the date currently in A1.
This is a bit stickier. If you follow the above steps but select cell A1 in step 1, then data validation won't work. Why? Because the date you enter in cell A1 will always be greater than or equal to the date you enter in A1—Excel doesn't compare to the previous date in A1 when doing data validation.
The only way to work through this problem is through the use of two macros. First, place the following macro in a regular module:
Sub Date_Validation() Dim dteDate As Date Dim strDate As String With Range("A1") ' Memo original date dteDate = CDate(.Text) ' Create date string strDate = Format(dteDate, "m\/d\/yy") With .Validation ' Delete old settings .Delete ' Set new data validation .Add _ Type:=xlValidateDate, _ AlertStyle:=xlValidAlertStop, _ Operator:=xlGreaterEqual, _ Formula1:=strDate .IgnoreBlank = False .InCellDropdown = True .InputTitle = "" .ErrorTitle = "Invalid Date Entry" .InputMessage = "" .ErrorMessage = _ "Date is older than the previous date (" & _ dteDate & ")." .ShowInput = True .ShowError = True End With End With End Sub
This macro needs to be called by another macro, this one placed in the worksheet's code window, so that it is triggered every time there is a change in the worksheet:
Private Sub Worksheet_Change(ByVal Target As Range) On Error Resume Next If Target = Range("A1") Then Date_Validation End Sub
The way these macros work is really quite interesting. Because you place the latter one in the worksheet's code window, it triggers every time there is a change to the worksheet. If the cell being changed is A1, then the Date_Validation macro is run.
The Date_Validation macro grabs the date from cell A1 and constructs a data validation rule for the cell. That's all it does—sets a data validation rule that won't allow a date to be entered in the cell that is earlier than the date currently in the cell.
The beauty of the macro is that once the data validation rule is in effect, then the next time cell A1 is changed, the data validation rule is triggered before the Worksheet_Change event is fired. Thus, the data validation rule makes sure that only a date greater than the current date can be entered. Once data validation is cleared, then the macro takes care of resetting the data validation rule, so it compares to the newly entered date.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10035) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Limiting Entry of Prior Dates.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Drop-down lists are handy in an Excel worksheet, and you they can be even more handy if a selection in one drop-down ...
Discover MoreData validation can be used to create lists of choices for entry into a particular cell. Using the techniques in this tip ...
Discover MoreWhen setting up Excel for data entry, you often have to be concerned with what values are acceptable. For example, if ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments