OzGrid

Mask Date Entry in Excel

< Back to Search results

 Category: [Excel]  Demo Available 

Mask Date Entry in Excel

 

Excel VBA: Mask Date Entry in Excel. Enter Dates in Excel With Masked Format

Mask Excel Date Entries.

Unlike Access, Excel does not allow for us to mask time and/or date entries. However, we can use the worksheet change event to achieve masked date entries. For the code to work dates should be entered as 6 digits, e.g. 010105, 121206 will change to 01/01/05 and 12/12/06 respectively. Note how the date mask is only applicable to the range A1:A100, but can be any range. You can change the display format (.NumberFormat = "dd/mm/yy") of the code to suit your needs. If using a US date format use.

To insert the code, right click on the Sheet name tab, select View Code and in here paste the code below;

Private Sub Worksheet_Change(ByVal Target As Range)

Dim StrVal As String

Dim dDate As Date



    If Target.Cells.Count > 1 Then Exit Sub

    If Intersect(Target, Range("A1:A100")) Is Nothing Then Exit Sub

     

     With Target

         StrVal = Format(.Text, "000000")

          If IsNumeric(StrVal) And Len(StrVal) = 6 Then

            Application.EnableEvents = False

            

            If Application.International(xlDateOrder) = 1 Then 'dd/mm/yy

                dDate = DateValue(Left(StrVal, 2) & "/" & Mid(StrVal, 3, 2) & "/" & Right(StrVal, 2))

            Else 'mm/dd/yy

                dDate = DateValue(Mid(StrVal, 3, 2) & "/" & Left(StrVal, 2) & "/" & Right(StrVal, 2))

            End If

            

            .NumberFormat = "dd/mm/yyyy"

            .Value = CDate(DateSerial(Year(dDate), Month(dDate), Day(dDate)))

           

          End If

    End With

           

     Application.EnableEvents = True



End Sub
 

See also:

Mask Time Entry in Excel

 

See also Index to Excel VBA Code and Index to Excel Freebies and Lesson 1 - Excel Fundamentals and Index to how to… providing a range of solutions.

 

Click here to visit our Free 24/7 Excel/VBA Help Forum where there are thousands of posts you can get information from, or you can join the Forum and post your own questions.


Gallery



stars (0 Reviews)