macro launch for #N/A result

rjplante

Well-known Member
Joined
Oct 31, 2008
Messages
567
Office Version
  1. 365
Platform
  1. Windows
I have a item list on one worksheet (wsA) and the first column is used to generate a named range "Master List" which is used in a pick form (wsB). The user will either select from the dropdown menu (column A) and then enter a quantity (column B). The item cost (column C) uses a vlookup formula to find the price from the table in wsA. There are some occasions where the user will type in a value in column A (wsB) that is not in the table on wsA. This will generate an #N/A value in column C because the price for the new item does not appear in the table in wsA. Is there a way to add a watch to column C for the value/result of "#N/A" and then run a macro to highlight the value in column A and delete the vlookup formula in column C, highlight column C and unlock the cell allowing the user to enter in their own price? Would I simply add in an error handler to the watch code so that if an error occurred in the formula, the result would be to call a formatting macro? I am not quite sure how to proceed.

Thanks for the feedback, any direction would help.
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Maybe you want to trigger macro checking using worksheet Calculate event. Then use VBA ISERROR to check for error in specific cell. If so, run a subroutine.
 
Upvote 0
I have worked up a solution and have it partially working. When I change the contents of the cell in column A, I want to run a calculation on column C of the same row. If the error "#N/A" appears, then run the rest of the code. What happens with my code is that when I change the cell and error appears, nothing happens. If I reselect the cell using the arrow keys, or select the cell with the mouse, the rest of the macro runs and the cells are formatted how I want them to be.

How can I get this to run and format the cells after hitting the Enter or Tab keys?

Thanks for the help.

VBA Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)


Dim KeyCells As Range
Dim myRow As Long

Set KeyCells = Range("A5:A5005")

If Not Application.Intersect(KeyCells, Range(Target.Address)) Is Nothing Then
    myRow = ActiveCell.Row
    ActiveCell.Offset(0, 2).Calculate

For n = 5 To 5005
    
    If IsError(Range("C" & myRow).Value) = True Then
    
        Range("C" & myRow).Locked = False
        Range("C" & myRow).Value = Range("C" & myRow).Offset(-1, 0).Value
        Range("A" & myRow).Interior.Color = RGB(255, 255, 0)
        Range("C" & myRow).Interior.Color = RGB(255, 255, 0)
        Range("A" & myRow).Validation.Delete
    
    End If

    Next n
End If

End Sub
 
Upvote 0
You are using Selection Change. Once you enter, the cursor move down (default). So, the active cell is not the initial position and the row number increases by 1.

You should use Worksheet Change event, but the same problem will happen. You should use Target.Row to capture the changed row.

myRow = Target.Row
Target.Offset(0, 2).Calculate


Anyway, you scan all row after that, So, I guess should not be any problem if wrong row.

You can just write
If IsError(Range("C" & myRow)) Then
 
Upvote 0
Solution
Thank you for the help, your suggestions worked out great!
 
Upvote 0

Forum statistics

Threads
1,214,644
Messages
6,120,709
Members
448,983
Latest member
Joaquim_Baptista

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top