Worksheet_Change private sub Run-time Error when deleting cell values

mws4ua

New Member
Joined
Sep 23, 2008
Messages
28
The code below is acting as expected...

  • If user enters "Personal" in any cell in Column J, cells on the same row in Columns K & L auto-fill with "Personal"
  • If user enters either "Misc." or "Other Meals" in Column K, cells on the same row in column L auto-fill with the same word

HOWEVER, any time multiple cells in (or among) columns J, K, and L are selected and the values cleared (Delete key) I get the error: "Run-time error '13': Type mismatch" and clicking Debug highlights the red code below.

Any ideas?

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    
  
    If Not Intersect(Target, Range("J:J")) Is Nothing Then
        [COLOR=#ff0000]If Target.Value = "Personal" Then[/COLOR]
                Target.Offset(0, 1).Value = Target.Offset(0, 0).Value 
                Target.Offset(0, 2).Value = Target.Offset(0, 0).Value 
        End If
    End If
    
    If Not Intersect(Target, Range("K:K")) Is Nothing Then
        If Target.Value = "Other Meals" Then
                Target.Offset(0, 1).Value = Target.Offset(0, 0).Value
        End If
    End If


    If Not Intersect(Target, Range("K:K")) Is Nothing Then
        If Target.Value = "Misc." Then
                Target.Offset(0, 1).Value = Target.Offset(0, 0).Value
        End If
        Else
            Set Target = Nothing
    End If
    
End Sub
 
Last edited:

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Try this:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    'Modified  5/29/2019  11:27:57 PM  EDT
    If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub
    If Not Intersect(Target, Range("J:J")) Is Nothing Then
        If Target.Value = "Personal" Then
                Target.Offset(0, 1).Value = Target.Value
                Target.Offset(0, 2).Value = Target.Value
        End If
    End If
    
    If Not Intersect(Target, Range("K:K")) Is Nothing Then
        If Target.Value = "Other Meals" Then Target.Offset(0, 1).Value = Target.Value
        If Target.Value = "Misc." Then Target.Offset(0, 1).Value = Target.Value
    End If
    End Sub
 
Upvote 0
Try this using OR

See Or marked in red:

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    'Modified  5/29/2019  11:34:17 PM  EDT
    If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub
    If Not Intersect(Target, Range("J:J")) Is Nothing Then
        If Target.Value = "Personal" Then
                Target.Offset(0, 1).Value = Target.Value
                Target.Offset(0, 2).Value = Target.Value
        End If
    End If
    
    If Not Intersect(Target, Range("K:K")) Is Nothing Then
        If Target.Value = "Other Meals" [COLOR=#ff0000]Or[/COLOR] Target.Value = "Misc." Then Target.Offset(0, 1).Value = Target.Value
    End If
    End Sub
 
Upvote 0
Or this:

You will see I used Resize
Marked in Red.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    'Modified  5/29/2019  11:41:25 PM  EDT
    If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub
    If Not Intersect(Target, Range("J:J")) Is Nothing Then
        If Target.Value = "Personal" Then Target.Offset(0, 1).[COLOR=#ff0000]Resize[/COLOR](, 2).Value = Target.Value
    End If
    
    If Not Intersect(Target, Range("K:K")) Is Nothing Then
        If Target.Value = "Other Meals" Or Target.Value = "Misc." Then Target.Offset(0, 1).Value = Target.Value
    End If
    End Sub
 
Upvote 0
Try this:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    'Modified  5/29/2019  11:27:57 PM  EDT
    If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub
    If Not Intersect(Target, Range("J:J")) Is Nothing Then
        If Target.Value = "Personal" Then
                Target.Offset(0, 1).Value = Target.Value
                Target.Offset(0, 2).Value = Target.Value
        End If
    End If
    
    If Not Intersect(Target, Range("K:K")) Is Nothing Then
        If Target.Value = "Other Meals" Then Target.Offset(0, 1).Value = Target.Value
        If Target.Value = "Misc." Then Target.Offset(0, 1).Value = Target.Value
    End If
    End Sub

I don't know how/why that bit of code works, but it certainly does. Thank you!

Try this using OR

See Or marked in red:

Or this:

You will see I used Resize
Marked in Red.

Thank you, too, for these efficiencies. My code now looks like your most recent post and it's working error free.

Thanks again.
 
Upvote 0
Glad I was able to help you.
Come back here to Mr. Excel next time you need additional assistance.
I don't know how/why that bit of code works, but it certainly does. Thank you!





Thank you, too, for these efficiencies. My code now looks like your most recent post and it's working error free.

Thanks again.
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,162
Members
453,021
Latest member
Justyna P

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