Jeremy posed a problem that is based on two cells, A1 and C1. These cells are designed to contain inches and millimeters, respectively. Jeremy wants a way that someone could enter a value in A1 and it would be converted to millimeters in C1. Conversely, they could enter a value in C1 and it would be converted to inches in A1.
Doing the conversion, of course, isn't the real issue. The problem is that if someone enters a value in A1, that value will overwrite any formula that may be in that cell, and mean that any subsequent value entered in cell C1 would not give the required conversion in the previously overwritten A1.
There are a couple of different ways that this could be approached. If you don't mind expanding your worksheet design to include two more cells, those cells could be used strictly for input and cells A1 and C1 could be used strictly for output. One of the input cells could contain the value to be converted and the other could contain the measurement unit of the input value (in or mm, for instance).
Of course, if you want to really limit yourself to two cells, then you will need to resort to using macros to do the actual conversion. You can use a worksheet event that is triggered every time a cell value is changed, and the event handler could check to see if the cell being changes is either A1 or C1. The following macro gives an example of how this could work:
Private Sub Worksheet_Change(ByVal Target As Range) Application.EnableEvents = False With ActiveSheet If Target = .[A1] Then .[C1].Value = .[A1].Value * 25.4 ElseIf Target = .[C1] Then .[A1].Value = .[C1].Value / 25.4 End If End With Application.EnableEvents = True End Sub
Note that you don't have to have any formulas in cells A1 or C1; the formulas are in the macro itself. If there is a change in cell A1 (inches are entered by the user), then the value in cell C1 is changed by the macro. Likewise, if there is a change in cell C1 (millimeters are entered by the user), then the value in cell A1 is changed by the macro. A change in any other cell besides A1 or C1 is ignored by the macro.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3277) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Developing Reciprocal Conversion Formulas.
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!
When you work with imported or pasted data in an Excel worksheet, you may see some strange looking characters at times. ...
Discover MorePart numbers can often be long, made up of other component elements. Breaking up part numbers into individual components ...
Discover MoreDifferent industries and different computer systems specify dates in all sorts of strange ways. If you need to convert a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2015-07-04 06:03:50
Willy Vanhaelen
The macro in this tip is badly conceived.
The change event can of course only occur when the sheet is active, so 'With ActiveSheet' is superfluous.
The macro should check which cell triggered the change event.
Instead 'If Target = .[A1] Then' checks if the contents of Target is the same as the contents of cell A1. That can lead to erroneous results. For instance try to enter 10 in cell A1. Cell C1 will show 254 (correct). Now enter 10 in cell C1: nothing happens, cell C1 still shows 254 because 'If Target = .[A1] Then' is true but that is not what we should be testing for!.
Here is a macro that does its job correctly and it is even shorter.
Private Sub Worksheet_Change(ByVal Target As Range)
Application.EnableEvents = False
Select Case Target.Address
Case "$A$1": [C1] = [A1] * 25.4
Case "$C$1": [A1] = [C1] / 25.4
End Select
Application.EnableEvents = True
End Sub
2015-07-03 11:15:01
Tom Bates
Allen, I had no idea that such a shortcut existed in VBA code:
[B1]
is a lot shorter than
Range("B1")
and
Cells(1,2)
Thanks for that tip! That will save me keystrokes in the immediate window for sure!
Tom
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2018 Sharon Parq Associates, Inc.
Comments