Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Adjusting Date Values by Keypress

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

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

Related Tips:

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!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

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

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.