Adjusting Date Values by Keypress

Written by Allen Wyatt (last updated January 21, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003


Robert notes that in a Quicken date field, if he presses the plus or minus key the date increments or decrements by one day. He would like to create this same sort of effect in Excel.

This is a harder problem to approach than one might assume, particularly in Excel. Since an action needs to be taken upon the pressing of a particular key (in this case, the plus or minus keys), one would naturally assume that the OnKey method could be used. Consider the following examples:

Sub Start_OnKey()
    Application.OnKey "{+}", "Plus1"
    Application.OnKey "-", "Minus1"
End Sub
Sub End_OnKey()
    Application.OnKey "{+}"
    Application.OnKey "-"
End Sub
Sub Plus1()
    If IsDate(ActiveCell) And Not ActiveCell.HasFormula Then
        ActiveCell.Value = ActiveCell.Value + 1
    End If
End Sub
Sub Minus1()
    If IsDate(ActiveCell) And Not ActiveCell.HasFormula Then
        ActiveCell.Value = ActiveCell.Value - 1
    End If
End Sub

According to all the VBA documentation, the above should work just fine, once you run the Start_OnKey macro. Every time a plus or minus key is pressed, the appropriate procedure is run to either increment the date or decrement the date. The problem is, it won't work on some versions of Excel. Why? Because the plus key, when pressed, apparently puts some versions of Excel into a special "formula entry" mode that bypasses the normal keyboard buffer relied upon by OnKey. So while pressing the minus key while a cell containing a date is selected produces the desired result, pressing the plus key does not.

For those versions of Excel where the plus key is a problem, the only solution is to change the keystrokes to something else. For instance, you could change the keypresses so that Ctrl+u is used to increment the date and Ctrl+d is used to decrement the date:

Sub Start_OnKey()
    Application.OnKey "^u", "Plus1"
    Application.OnKey "^d", "Minus1"
End Sub
Sub End_OnKey()
    Application.OnKey "^u"
    Application.OnKey "^d"
End Sub

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7197) applies to Microsoft Excel 97, 2000, 2002, and 2003.

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

Copying Formatting

Excel provides a couple of different ways to copy formatting from one cell to another. Perhaps the easiest way is to use ...

Discover More

Formatting Partial Results of a Search

The Find and Replace capabilities of Word are, simply, quite astounding. This is particularly true when using wildcard ...

Discover More

Copying a Chart and Related Shapes to a Word Document

Excel and Word are intended to work together, but sometimes it can seem that getting them to do so isn't that intuitive. ...

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (menu)

Converting an Unsupported Date Format

Excel makes it easy to import information created in other programs. Converting the imported data into something you can ...

Discover More

How Excel Stores Dates and Times

Excel stores dates and times internally using what is called a serial number. This tip explains how that serial number is ...

Discover More

Determining the Day of the Month

Want to figure out the day of the month represented by a particular date? You can use the Day function in VBA to get the ...

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 5 - 3?

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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.