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: Entering Dates without Separators.
Written by Allen Wyatt (last updated December 9, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Different people enter data in different ways. When you enter information into a cell, Excel tries to figure out what type of information you are entering. If you enter a number such as 08242020, Excel assumes you are entering a numeric value, and treats it accordingly. What if the number you enter actually is a date, without any separators? Can Excel understand what you are entering?
Unfortunately, Excel cannot. Why? Because you have given it no indication that this should be a date. (Excel keys on separators, not on numeric values.) If you or your data entry people cannot change their input habits so that separators are also entered, then you will need some sort of a workaround to convert the entered information to an actual date value.
Your first thought might be that you could use a custom format to display the information. Consider the following custom format:
##"/"##"/"####
This format would display the number 08142020 as 8/14/2020. The only problem is that it only changes the display of the number—if you want to use the date as a real Excel date, you cannot do so because you haven't converted the value into something that Excel recognizes as a date.
If the values input were very consistent in their format, and if they were input as text instead of as numeric values, then there is an easy way you can convert them to dates. By very consistent, I mean that the input always used two digits for the month, two for the day, and four for the year. In addition, the cells containing the values must be formatted as text. In this instance, you can follow these steps:
Figure 1. The Convert Text to Columns Wizard.
If all went well, Excel should have parsed the text values as dates, and you can delete the original column. If this did not work, then it means that either the original values were not formatted as text, or eight digits were not used to enter all the dates.
Another possible solution is to use a formula to convert the entered values into actual dates. The following is one such formula:
=DATE(RIGHT(A1,4),LEFT(A1,IF(LEN(A1) = 8,2,1)),LEFT(RIGHT(A1,6),2))
This formula assumes that the entered date (the one without separators) is in cell A1. The formula will work with either seven- or eight-digit dates.
If you prefer custom functions, you can create one in VBA that examines the data being passed, converts it to a date/time format, and then returns the result. The following function is very versatile in this regard; it will work with both American and European date formats:
Function DateTime(dblDateTime As Double, _ Optional bAmerican As Boolean = True) ' Converts Date and time "number" without ' delimiters into an Excel serial number (which ' can then be formatted with the Excel ' date/time formats) ' If optional argument is TRUE (or missing), ' function assumes value is of form: ' [m]mddyyyy.hhmm (leading "0" not required) ' If optional argument is FALSE, function ' assumes value is of form: ' [d]dmmyyyy.hhmm (leading "0" not required) Dim iYear As Integer Dim iMonth As Integer Dim iDay As Integer Dim iHour As Integer Dim iMin As Integer iYear = Int((dblDateTime / 10000 - _ Int(dblDateTime / 10000)) * 10000) iDay = Int((dblDateTime / 1000000 - _ Int(dblDateTime / 1000000)) * 100) iMonth = Int((dblDateTime / 1000000)) iHour = Int((dblDateTime - Int(dblDateTime)) * 100) iMin = Int((dblDateTime * 100 - _ Int(dblDateTime * 100)) * 100 + 0.5) If bAmerican Then DateTime = DateSerial(iYear, iMonth, iDay) Else DateTime = DateSerial(iYear, iDay, iMonth) End If DateTime = DateTime + (iHour + iMin / 60) / 24 End Function
This macro function assumes that the data being passed to it is a numeric value, as would normally happen when inputting dates without separators. (Refer back to the logic on this at the beginning of the tip.)
As you can tell, there are a number of workarounds, but none of them is as simple as just entering separators when entering the dates. If training yourself or your data input people to do this is difficult, you might consider setting up some data validation rules for the input cells. These rules can check to make sure that you are entering information using a specific format (such as a date with separators) and stop you if you are not. (How you create data validation rules has been covered in other issues of ExcelTips.)
For additional ways to enter dates and times without the separators (using macros), check out this helpful page on Chip Pearson's site:
http://www.cpearson.com/Excel/DateTimeEntry.htm
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11400) 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: Entering Dates without Separators.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Excel is great when it comes to working with dates and times. You can even do math on dates. One such easy manipulation ...
Discover MoreIf you use a text function with a date or time, you'll get an error. To understand why this occurs (and how to get around ...
Discover MoreNeed a way to enter dates for every other Tuesday (or some other regular interval)? Excel makes it easy, providing ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-12-10 05:09:26
Philip
Recently I found out that if you use the Text-To-Columns button and you make sure that NONE of the delimiters in the first dialog is selected, and in the next dialog you select the date convention, Excel will actually convert your dates "in-situ" ... no problems with fixed width setting ...
2021-03-12 12:18:12
J. Woolley
@David
I found your comment about VBA's Format(...) function interesting. I wasn't previously aware. Microsoft's Office VBA Reference describing the Format function says it recognizes / as a date separator in its second argument, but "The actual character used as the date separator in formatted output is determined by your system settings." For Windows 10, these settings are governed by Settings > Time & Language > Change data formats (or Control Panel > Region).
My earlier comment (perhaps too brief) was simply intended to describe an alternative method for formatting a date by use of Excel's Text(...) function, which apparently is not as sensitive to system settings.
As it turns out, you could have used either of the following two VBA methods to override the system settings when formatting a date:
Format(Date, "mm\/dd\/yyyy")
WorksheetFunction.Text(Date, "mm/dd/yyyy")
https://sites.google.com/view/MyExcelToolbox/
2021-03-08 11:02:40
David Bonin
Mr. Wooley,
Thank you. I'm happy with the one I put in place and I see no need to change it now.
My posting was more of a cautionary tale that Excel VBA doesn't always do what you explicitly tell you to do and, if one happened to run across a similar situation, I offered a suitable workaround.
2021-03-07 12:44:12
Willy Vanhaelen
Entering the date [d]dmmyyyy / [m]mddyyyy directly in the cell is in my opinion the quickest and easiest. This can be done with an event macro. I developed one for entering dates without separators in column A which is very common. The macro converts your entry into an Excel date number.
The macro is made for European dates because that's the way my system is configured. It is simple to change it for US dates. Simply swap the MID and LEFT functions in the DateSerial function and change [d]dmmyyyy into [m]mddyyyy.
Private Sub Worksheet_Change(ByVal Target As Range)
On Error GoTo done
If Target.Column <> 1 Or Target.Cells.Count > 1 Or Target = "" Then Exit Sub
Application.EnableEvents = False
If Len(Target) = 7 Then Target = "'0" & Target
If Len(Target) <> 8 Then
MsgBox "Enter the date as [d]dmmyyyy"
GoTo done
End If
Target = DateSerial(Right(Target, 4), Mid(Target, 3, 2), Left(Target, 2))
done: Application.EnableEvents = True
End Sub
You can even format the cell to display the date the way you entered it but it is still an Excel date that can be used in calculations. To do so insert the following code line just above "done:":
Target.NumberFormat = "[d]dmmyyyy" 'or "[m]mddyyyy" for US dates.
2021-03-07 10:31:34
J. Woolley
@David
You could have used this: WorksheetFunction.Text(Date, "mm/dd/yyyy")
https://sites.google.com/view/MyExcelToolbox/
2021-03-06 12:53:42
David Bonin
I recently discovered an interesting quirk with Excel and Windows 10.
I set my PC to use a date format of yyyy-mm-dd. Why? Because it visually collates better in Windows Explorer. My PC displays today's date as 2021-03-06.
When importing / exporting data from / to a mainframe database using Visual Basic, I needed to convert dates from Excel's numeric values to string values in the format of mm/dd/yyyy.
I figured I could use something like this in VBA to create a string value of today's date:
Format( Date, "mm/dd/yyyy" )
Nope that doesn't work. VBA creates a string value in the format of mm-dd-yyyy. Essentially it ignored my explicit instructions about the delimiters.
I found I needed to use this instead:
Format( Date, "mm" ) & "/" & Format( Date, "dd" ) & "/" & Format( Date, "yyyy" )
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