Limiting Input by Time of Day

Written by Allen Wyatt (last updated November 12, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


Steven needs to ensure that nobody enters information into a worksheet between 4:00 pm and 6:30 pm each day. He wonders if it is possible to use Data Validation to prevent a user from entering information in a worksheet during a particular time each day.

There are two general ways you can go about this. One approach is to use Data Validation to check the time and either allow or disallow data entry.

  1. Select all the cells in the worksheet.
  2. Display the Data tab of the ribbon.
  3. Click the Data Validation tool in the Data Tools group. Excel displays the Data Validation dialog box. (See Figure 1.)
  4. Figure 1. The Data Validation dialog box.

  5. Using the Allow drop-down list, choose Custom.
  6. Enter the following in the Formula box:
  7.        =OR(24*MOD(NOW(),1)<16,24*MOD(NOW(),1)>18.5)
    
  8. Make changes on the Error Alert tab, as desired.
  9. Click OK.

The problem with this approach is in the very first step: You need to select all the cells in the worksheet in order to prevent data being entered in any of them. Plus, if you already are using Data Validation in any of the cells, this approach will overwrite those settings.

For these reasons, it may be better to use a macro-based approach. All such approaches can utilize event handlers to check for any changes. The following relies on the Worksheet_Change event, which means it is triggered only when Excel detects a change in the worksheet.

Private Sub Worksheet_Change(ByVal Target As Range)
    Dim sMsg As String

    sMsg = "No entries allowed between 4:00 pm and 6:30 pm!"
    If Time >= "4:00:00 PM" And Time <= "6:30:00 PM" Then
        MsgBox sMsg, vbCritical
        With Application
            .EnableEvents = False
            .Undo   ' This undoes the change the person made
            .EnableEvents = True
        End With
    End If
End Sub

Essentially, every time there is a change in the worksheet, the handler checks to see if it is between 4:00 pm and 6:30 pm. If it is, then a message box is displayed to indicate the error, and then the .Undo method is used to roll back any change that was attempted.

If you prefer, you could take a different approach and protect the worksheet if it is within the banned time:

Private Sub Worksheet_Activate()
     If Time >= "4:00:00 PM" And Time <= "6:30:00 PM" Then
        ActiveSheet.Protect
        MsgBox "Worksheet is protected."
    Else
        ActiveSheet.Unprotect
        MsgBox "You are free to edit now."
    End If
End Sub

The Worksheet_Activate event handler is invoked every time the worksheet is activated (selected). If the worksheet is activated anytime outside of the banned time, then it is unprotected. Of course, the user could still manually unprotect the worksheet even during the banned time, so it is a good idea to use this approach in conjunction with an approach that is triggered every time a change is attempted, as discussed earlier.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13503) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Determining Winners, by Category

Do you need to determine the top three values in a range of columns? The techniques discussed in this tip will come in ...

Discover More

Automatic Text in an E-mail

When creating an e-mail address hyperlink using the Insert Hyperlink dialog box, Excel allows you to enter a subject for ...

Discover More

Three-Dimensional Transpositions

Excel makes it easy to transpose your data so that rows become columns and columns rows. It doesn't have a built-in ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Locking All Non-Empty Cells

Need to make sure that your worksheet is locked, with only the blank cells accessible to editing? You can do this easily ...

Discover More

Stopping a Worksheet from being Moved or Copied

Want to stop a user from moving or copying a worksheet? This task (like many) can be more complex than one would hope. ...

Discover More

Hiding and Protecting Columns

Want to hide certain columns within a worksheet so the contents are not visible to others? The answer lies in formatting ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 1 + 0?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.