2 codes same page

JOEE1979

Active Member
Joined
Dec 18, 2022
Messages
287
Office Version
  1. 365
Platform
  1. Windows
If I have 2 code and need them to be both in "sheet1", and they both have the same heading "Private Sub Worksheet_Change(ByVal Target As Range)".

How can I get them to both work together? is there something I need to add between both codes?


VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim f As Range
  Dim resp As VbMsgBoxResult
  Dim i As Long
 
  If Not Intersect(Target, Range("M:M")) Is Nothing Then
    If Target.Count > 1 Then Exit Sub
    If Target.Value = "Yes" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("K:L").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("K:L").Find(Range("H" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("K" & i).Value = "" Then
              Range("K" & i).Value = Range("H" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
      
    ElseIf Target.Value = "No" Then
      i = 475
      resp = MsgBox("Is unit being shopped?", vbYesNo + vbQuestion)
      If resp = vbYes Then
        Do While True
          If Range("A" & i).Value = "" Then
            Range("A" & i).Value = Range("H" & Target.Row).Value
            Range("C" & i).Value = Range("I" & Target.Row).Value
            Range("D" & i).Value = Range("K" & Target.Row).Value
            Range("E" & i).Value = "Running Repair"
            Exit Do
          End If
          i = i + 1
        Loop
      End If
    End If
      
  End If
End Sub

Private Sub Worksheet_Change(ByVal Target As Range)
  Dim f As Range
  Dim resp As VbMsgBoxResult
  Dim i As Long
 
  If Not Intersect(Target, Range("F:F")) Is Nothing Then
    If Target.Count > 1 Then Exit Sub
    If Target.Value = "Completed" Then
    If Target.Offset(0, -1).Value = "Running Repair" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("I:J").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("I:J").Find(Range("A" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("I" & i).Value = "" Then
              Range("I" & i).Value = Range("A" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
    End If
  End If
 
  End If
End Sub
 
Last edited:

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
You cant have 2 worksheet_change events on the same sheet.
I don't have Excel atm, but they will need to be combined as one.
UNTESTED.....
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim f As Range, resp As VbMsgBoxResult, i As Long
 
  If Not Intersect(Target, Range("M:M")) Is Nothing Then
    If Target.Count > 1 Then Exit Sub
    If Target.Value = "Yes" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("K:L").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("K:L").Find(Range("H" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("K" & i).Value = "" Then
              Range("K" & i).Value = Range("H" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
If Not Intersect(Target, Range("F:F")) Is Nothing Then
    If Target.Value = "Completed" Then
    If Target.Offset(0, -1).Value = "Running Repair" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("I:J").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("I:J").Find(Range("A" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("I" & i).Value = "" Then
              Range("I" & i).Value = Range("A" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
    End If
  End If
 
  End If
    ElseIf Target.Value = "No" Then
      i = 475
      resp = MsgBox("Is unit being shopped?", vbYesNo + vbQuestion)
      If resp = vbYes Then
        Do While True
          If Range("A" & i).Value = "" Then
            Range("A" & i).Value = Range("H" & Target.Row).Value
            Range("C" & i).Value = Range("I" & Target.Row).Value
            Range("D" & i).Value = Range("K" & Target.Row).Value
            Range("E" & i).Value = "Running Repair"
            Exit Do
          End If
          i = i + 1
        Loop
      End If
    End If
      
  End If
End Sub
 
Upvote 0
Solution
You cant have 2 worksheet_change events on the same sheet.
I don't have Excel atm, but they will need to be combined as one.
UNTESTED.....
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim f As Range, resp As VbMsgBoxResult, i As Long
 
  If Not Intersect(Target, Range("M:M")) Is Nothing Then
    If Target.Count > 1 Then Exit Sub
    If Target.Value = "Yes" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("K:L").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("K:L").Find(Range("H" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("K" & i).Value = "" Then
              Range("K" & i).Value = Range("H" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
If Not Intersect(Target, Range("F:F")) Is Nothing Then
    If Target.Value = "Completed" Then
    If Target.Offset(0, -1).Value = "Running Repair" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("I:J").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("I:J").Find(Range("A" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("I" & i).Value = "" Then
              Range("I" & i).Value = Range("A" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
    End If
  End If
 
  End If
    ElseIf Target.Value = "No" Then
      i = 475
      resp = MsgBox("Is unit being shopped?", vbYesNo + vbQuestion)
      If resp = vbYes Then
        Do While True
          If Range("A" & i).Value = "" Then
            Range("A" & i).Value = Range("H" & Target.Row).Value
            Range("C" & i).Value = Range("I" & Target.Row).Value
            Range("D" & i).Value = Range("K" & Target.Row).Value
            Range("E" & i).Value = "Running Repair"
            Exit Do
          End If
          i = i + 1
        Loop
      End If
    End If
     
  End If
End Sub
You were close, I got it to work this way, Thanks


VBA Code:
'sign ins
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim f As Range
  Dim resp As VbMsgBoxResult
  Dim i As Long
 
  If Not Intersect(Target, Range("M:M")) Is Nothing Then
    If Target.Count > 1 Then Exit Sub
    If Target.Value = "Yes" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("K:L").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("K:L").Find(Range("H" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("K" & i).Value = "" Then
              Range("K" & i).Value = Range("H" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
      
    ElseIf Target.Value = "No" Then
      i = 475
      resp = MsgBox("Is unit being shopped?", vbYesNo + vbQuestion)
      If resp = vbYes Then
        Do While True
          If Range("A" & i).Value = "" Then
            Range("A" & i).Value = Range("H" & Target.Row).Value
            Range("C" & i).Value = Range("I" & Target.Row).Value
            Range("D" & i).Value = Range("K" & Target.Row).Value
            Range("E" & i).Value = "Running Repair"
            Exit Do
          End If
          i = i + 1
        Loop
      End If
    End If
      
  End If
'Running Repair
If Not Intersect(Target, Range("F:F")) Is Nothing Then
    If Target.Count > 1 Then Exit Sub
    If Target.Value = "Completed" Then
    If Target.Offset(0, -1).Value = "Running Repair" Then
      resp = MsgBox("Is unit returned to service?", _
        vbYesNo + vbQuestion)
      If resp = vbYes Then
        Set f = Range("I:J").Find("RETURNED TO SERVICE", , xlValues, xlPart, , , False)
        If Not f Is Nothing Then
          i = f.Row + 2
          Set f = Range("I:J").Find(Range("A" & Target.Row).Value, , xlValues, xlWhole, , , False)
          If Not f Is Nothing Then
            MsgBox "This unit already exists in the section."
            Exit Sub
          End If
          Do While True
            If Range("I" & i).Value = "" Then
              Range("I" & i).Value = Range("A" & Target.Row).Value
              Exit Do
            End If
            i = i + 1
          Loop
        End If
      End If
    End If
  End If
 
  End If
  End Sub
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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