advice & fixing code to clear cells if another is empty

MKLAQ

Active Member
Joined
Jan 30, 2021
Messages
387
Office Version
  1. 2016
Platform
  1. Windows
hello
I try making macro by match B2 into sheet2 with column A for sheet1 and brings the values into sheet2 for cells B3:B5. every thing is ok except one thing . if the cell B2 is empty should clear B3:B5 ,but it doesn't clear .
any help to fix it please?
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim Fnd As Range, sh1 As Worksheet
Set sh1 = sheet1
  On Error Resume Next
 
   If Target.Address(0, 0) = "B2" And Target.Value <> "" Then
      Set Fnd = sheet1.Range("A:A").Find(Target.Value, , , xlWhole, , , False, , False)
      If Not Fnd Is Nothing Then
      With sheet2
       .Range("B3").Value = Fnd.Offset(, 1).Value
        .Range("B4").Value = Fnd.Offset(, 3).Value
        .Range("B5").Value = Fnd.Offset(, 2).Value
        End With
        Else
        sheet2.Range("B3").Value = ""
        sheet2.Range("B4").Value = ""
        sheet2.Range("B5").Value = ""
        End If
     
   End If
End Sub
thanks
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
As it stands your code will only clear B3:B5 if the Target Value is NOT found in column A.
Since the clear code is in the Else part of If Not Fnd is Nothing. It will not get to this code since it does NOT meet the criteria Target.Value <> ""

You could duplicate the clear lines in an added Else statement for the first If statement so that if Target.Value = "" it performs that else statement.

I think that rather than duplicate, reversing your logic might work for you. ie you only want values to exist if Target.Value is found and <> "".

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim Fnd As Range, sh1 As Worksheet
Set sh1 = Sheet1
On Error Resume Next

    If Target.Address(0, 0) = "B2" Then
        'If B2 is changed intialise values to be updated
        sheet2.Range("B3").Value = ""
        sheet2.Range("B4").Value = ""
        sheet2.Range("B5").Value = ""
        
        Set Fnd = Sheet1.Range("A:A").Find(Target.Value, , , xlWhole, , , False, , False)
        'Only update relevant fields if B2 value is found
        If Not Fnd Is Nothing Then
            With sheet2
                .Range("B3").Value = Fnd.Offset(, 1).Value
                .Range("B4").Value = Fnd.Offset(, 3).Value
                .Range("B5").Value = Fnd.Offset(, 2).Value
            End With
        End If
    End If
End Sub
 
Upvote 0
Solution
actually I hesitated in the beginning to put it in the beginning of the code , I thought to be problem from the whole code something isn't logic .

I thought may be need arranging the procedures to become more logic .

much appreciated :)
 
Upvote 0

Forum statistics

Threads
1,214,606
Messages
6,120,487
Members
448,967
Latest member
visheshkotha

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