VBA to Insert Mismatched Row in separate worksheet

MacOrch

New Member
Joined
Aug 14, 2024
Messages
11
Office Version
  1. 365
Platform
  1. Windows
Long time lurker, first time poster. Usually I can find what I need in previous threads, but this one has beat me.

I have 2 worksheets that I use the below code to compare data in the two.
The code looks for the ID number in Sheet1 ColumnA and matches it to the ID number in Sheet2 ColumnA. Any cells in that row that do not match are highlighted on Sheet2 in yellow. Any missing ID from column A are highlighted red.

My question is how can I copy the entire row of the mismatched cells from Sheet2 and insert it below the corresponding row in Sheet1, and add the missing ID rows the bottom of the data in Sheet1.

Ideally Sheet1 end result would look like this:
2024-08-14_16-21-57.jpg


VBA Code:
Sub Changes()
Range("A1").Select

    Dim ws1 As Worksheet, Ws2 As Worksheet
    Dim ws1Data As Range, f As Range, cell As Range
    Dim icol As Long

    Set ws1Data = Worksheets("Sheet1").Columns(1).SpecialCells(xlCellTypeConstants)

    With Worksheets("Sheet2")
        For Each cell In Intersect(.UsedRange, .Columns(1)).SpecialCells(xlCellTypeConstants)
            Set f = ws1Data.Find(what:=cell.Value, LookIn:=xlValues, LookAt:=xlWhole)
            If f Is Nothing Then
                Intersect(cell.EntireRow, .UsedRange).Interior.ColorIndex = 3
            Else
                For icol = 1 To .Range(cell, .Cells(cell.Row, .Columns.Count).End(xlToLeft)).Columns.Count - 1
                    If f.Offset(, icol) <> cell.Offset(, icol) Then
                        cell.Offset(, icol).Interior.ColorIndex = 6
                        
                    End If
                Next icol
            End If
        Next cell
End With
Range("A1").Select

End Sub
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Welcome to the MrExcel board!

See how this goes with a copy of your workbook.

VBA Code:
Sub Changes_v2()
    Dim ws1 As Worksheet
    Dim ws1Data As Range, f As Range, cell As Range
    Dim icol As Long, nr As Long
    Dim bYellow As Boolean

    Set ws1Data = Worksheets("Sheet1").Columns(1).SpecialCells(xlCellTypeConstants)
    nr = Worksheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row + 1
    With Worksheets("Sheet2")
        For Each cell In Intersect(.UsedRange, .Columns(1)).SpecialCells(xlCellTypeConstants)
            bYellow = False
            Set f = ws1Data.Find(what:=cell.Value, LookIn:=xlValues, LookAt:=xlWhole)
            If f Is Nothing Then
                With Intersect(cell.EntireRow, .UsedRange)
                  .Interior.ColorIndex = 3
                  .Copy Destination:=Worksheets("Sheet1").Range("A" & nr)
                  nr = nr + 1
                End With
            Else
                For icol = 1 To .Range(cell, .Cells(cell.Row, .Columns.Count).End(xlToLeft)).Columns.Count - 1
                    If f.Offset(, icol) <> cell.Offset(, icol) Then
                        cell.Offset(, icol).Interior.ColorIndex = 6
                        bYellow = True
                    End If
                Next icol
                If bYellow Then
                  f.Offset(1).EntireRow.Insert
                  Intersect(cell.EntireRow, .UsedRange).Copy Destination:=f.Offset(1)
                  f.Offset(1).Resize(, 2).ClearContents
                  nr = nr + 1
                End If
            End If
        Next cell
    End With
    Range("A1").Select
End Sub
 
Upvote 0
Welcome to the MrExcel board!

See how this goes with a copy of your workbook.

VBA Code:
Sub Changes_v2()
    Dim ws1 As Worksheet
    Dim ws1Data As Range, f As Range, cell As Range
    Dim icol As Long, nr As Long
    Dim bYellow As Boolean

    Set ws1Data = Worksheets("Sheet1").Columns(1).SpecialCells(xlCellTypeConstants)
    nr = Worksheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row + 1
    With Worksheets("Sheet2")
        For Each cell In Intersect(.UsedRange, .Columns(1)).SpecialCells(xlCellTypeConstants)
            bYellow = False
            Set f = ws1Data.Find(what:=cell.Value, LookIn:=xlValues, LookAt:=xlWhole)
            If f Is Nothing Then
                With Intersect(cell.EntireRow, .UsedRange)
                  .Interior.ColorIndex = 3
                  .Copy Destination:=Worksheets("Sheet1").Range("A" & nr)
                  nr = nr + 1
                End With
            Else
                For icol = 1 To .Range(cell, .Cells(cell.Row, .Columns.Count).End(xlToLeft)).Columns.Count - 1
                    If f.Offset(, icol) <> cell.Offset(, icol) Then
                        cell.Offset(, icol).Interior.ColorIndex = 6
                        bYellow = True
                    End If
                Next icol
                If bYellow Then
                  f.Offset(1).EntireRow.Insert
                  Intersect(cell.EntireRow, .UsedRange).Copy Destination:=f.Offset(1)
                  f.Offset(1).Resize(, 2).ClearContents
                  nr = nr + 1
                End If
            End If
        Next cell
    End With
    Range("A1").Select
End Sub
Peter, you are a genius.
Works perfect. Thanks for your help.
 
Upvote 0
You're welcome. Glad to help. Thanks for the follow-up. :)

BTW, if you have future questions, so that we could actually use your sample data, I suggest that you investigate XL2BB
 
Upvote 0
Welcome to the MrExcel board!

See how this goes with a copy of your workbook.

VBA Code:
Sub Changes_v2()
    Dim ws1 As Worksheet
    Dim ws1Data As Range, f As Range, cell As Range
    Dim icol As Long, nr As Long
    Dim bYellow As Boolean

    Set ws1Data = Worksheets("Sheet1").Columns(1).SpecialCells(xlCellTypeConstants)
    nr = Worksheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row + 1
    With Worksheets("Sheet2")
        For Each cell In Intersect(.UsedRange, .Columns(1)).SpecialCells(xlCellTypeConstants)
            bYellow = False
            Set f = ws1Data.Find(what:=cell.Value, LookIn:=xlValues, LookAt:=xlWhole)
            If f Is Nothing Then
                With Intersect(cell.EntireRow, .UsedRange)
                  .Interior.ColorIndex = 3
                  .Copy Destination:=Worksheets("Sheet1").Range("A" & nr)
                  nr = nr + 1
                End With
            Else
                For icol = 1 To .Range(cell, .Cells(cell.Row, .Columns.Count).End(xlToLeft)).Columns.Count - 1
                    If f.Offset(, icol) <> cell.Offset(, icol) Then
                        cell.Offset(, icol).Interior.ColorIndex = 6
                        bYellow = True
                    End If
                Next icol
                If bYellow Then
                  f.Offset(1).EntireRow.Insert
                  Intersect(cell.EntireRow, .UsedRange).Copy Destination:=f.Offset(1)
                  f.Offset(1).Resize(, 2).ClearContents
                  nr = nr + 1
                End If
            End If
        Next cell
    End With
    Range("A1").Select
End Sub
How can I add to this code to clear the contents of the adjacent cells in the same rows as the yellow filled cells?
So that it looks something like this:
2024-08-15_16-09-01.jpg

Cheers
 
Upvote 0
How can I add to this code to clear the contents of the adjacent cells in the same rows as the yellow filled cells?
So that it looks something like this:
Could we have some smallish sample data (say 10-12 rows) with XL2BB (see my previous post) from both sheets that might produce something like that?
 
Upvote 0
Sorry Peter I'm on a corporate system and Add-Ins are blocked, so I'll try and explain with some pics.
Firstly the code you posted above works great.
What I'm trying to achieve in addition is to clear the contents of any cells in the same row as a yellow cell, however contents of the yellow cell needs to remain.

This pic shows how my data looks after running the above code
2024-08-16_10-56-46.jpg


I'm hoping to add to the code to clear the contents of all cells on the same row as a yellow cells.
End result would look like this
2024-08-16_10-57-51.jpg


Something like this code below, but retain contents of Yellow cells.

VBA Code:
Sub ClearRowContents()
    Dim ws As Worksheet
    Dim rng As Range
    Dim cell As Range
  
    Set ws = ThisWorkbook.Sheets("Sheet1")
    Set rng = ws.Range("A1:A100")

    For Each cell In rng
 
        If IsEmpty(cell.Value) Then
            cell.EntireRow.ClearContents
        End If
    Next cell
End Sub

Hope this makes sense.
 
Upvote 0
I'm on a corporate system and Add-Ins are blocked, so I'll try and explain with some pics.
Fair enough on the first point (for future questions I suggest you point that out in post 1 so helpers don't keep asking :))
On the second point, I believe I already understood the requirement, I just wanted some realistic data to test with.
In particular, I would like to know what was on 'Sheet2' that leads to those final results shown above. Can you show me that either with another picture or simply copy/paste from your Excel into your post? Make sur that I can see what is in columns A & B of that sheet as well as the data further to the right.
 
Upvote 0
Fair enough on the first point (for future questions I suggest you point that out in post 1 so helpers don't keep asking :))
On the second point, I believe I already understood the requirement, I just wanted some realistic data to test with.
In particular, I would like to know what was on 'Sheet2' that leads to those final results shown above. Can you show me that either with another picture or simply copy/paste from your Excel into your post? Make sur that I can see what is in columns A & B of that sheet as well as the data further to the right.

Hi Peter thanks for the tip.
My data on both sheets is from the same report, so layout is the same only content is varied.
Data from Sheet1 comes from a generated report run 6 weeks earlier, data from Sheet2 comes from the same report run today.
ColumnA = ID, ColumnB = Position, ColumnC to P = Dates
Your amended code above works great, but if possible I would only like the highlighted cells from Sheet2 inserted below their corresponding rows on Sheet1.
Thanks

Sheet2 Data
IDPositionMonday 29 Jul 2024Tuesday 30 Jul 2024Wednesday 31 Jul 2024Thursday 01 Aug 2024Friday 02 Aug 2024Saturday 03 Aug 2024Sunday 04 Aug 2024
11066SC14:00-22:0014:00-22:0014:00-22:0014:00-22:00DAY OFFDAY OFFDAY OFF
11128SCDAY OFF14:00-22:00DAY OFF14:00-22:0014:00-22:0014:00-22:00DAY OFF
11355SC06:00-14:0006:00-14:0006:00-14:0014:00-22:0014:00-22:0014:00-22:00DAY OFF
11499SC14:00-22:0014:00-22:0014:00-22:0014:00-22:00DAY OFFDAY OFFDAY OFF
12649SCDAY OFFDAY OFFDAY OFF08:00-16:0008:00-16:0006:00-14:0014:00-22:00
12702SC14:00-22:0014:00-22:0014:00-22:0022:00-06:0022:00-06:00DAY OFFDAY OFF
12880SC14:00-22:00DAY OFF22:00-06:0022:00-06:0022:00-06:00DAY OFFDAY OFF
13089SC06:00-14:0006:00-14:0006:00-14:0006:00-14:0006:00-14:00DAY OFFDAY OFF
13095SCDAY OFFDAY OFFDAY OFFDAY OFFDAY OFFDAY OFFDAY OFF

Sheet1 Data
IDPositionMonday 29 Jul 2024Tuesday 30 Jul 2024Wednesday 31 Jul 2024Thursday 01 Aug 2024Friday 02 Aug 2024Saturday 03 Aug 2024Sunday 04 Aug 2024
11066SC14:00-22:0014:00-22:0014:00-22:0014:00-22:00DAY OFFDAY OFFDAY OFF
11128SC06:00-14:0006:00-14:0006:00-14:0014:00-22:0014:00-22:0014:00-22:00DAY OFF
11355SC06:00-14:0006:00-14:0006:00-14:0014:00-22:0014:00-22:0014:00-22:00DAY OFF
12649SCDAY OFFDAY OFFDAY OFF08:00-16:0008:00-16:0006:00-14:0014:00-22:00
12702SC14:00-22:0014:00-22:0022:00-06:0022:00-06:0022:00-06:00DAY OFFDAY OFF
12880SC14:00-22:0014:00-22:0022:00-06:0022:00-06:0022:00-06:00DAY OFFDAY OFF
13089SC06:00-14:0006:00-14:0006:00-14:0006:00-14:0006:00-14:00DAY OFFDAY OFF
13095SCDAY OFFDAY OFFDAY OFFDAY OFFDAY OFFDAY OFFDAY OFF
13328SC22:00-06:0022:00-06:0022:00-06:00DAY OFFDAY OFF06:00-14:0006:00-14:00
11499SC14:00-22:0014:00-22:0014:00-22:0014:00-22:00DAY OFFDAY OFFDAY OFF
 
Upvote 0
Thanks for the sample data. See how this one goes.

VBA Code:
Sub Changes_v3()
    Dim rw As Variant
    Dim ws1Data As Range, f As Range, cell As Range
    Dim icol As Long, nr As Long, cols As Long
    Dim bYellow As Boolean

    Set ws1Data = Worksheets("Sheet1").Columns(1).SpecialCells(xlCellTypeConstants)
    nr = Worksheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row + 1
    With Worksheets("Sheet2")
        cols = .Cells(1, Columns.Count).End(xlToLeft).Column - 2
        ReDim rw(1 To 1, 1 To cols)
        For Each cell In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
            bYellow = False
            Set f = ws1Data.Find(what:=cell.Value, LookIn:=xlValues, LookAt:=xlWhole)
            If f Is Nothing Then
                With Intersect(cell.EntireRow, .UsedRange)
                  .Interior.ColorIndex = 3
                  .Copy Destination:=Worksheets("Sheet1").Range("A" & nr)
                  nr = nr + 1
                End With
            Else
                For icol = 1 To cols
                  rw(1, icol) = vbNullString
                  If f.Offset(, icol + 1).Value <> cell.Offset(, icol + 1).Value Then
                      cell.Offset(, icol + 1).Interior.ColorIndex = 6
                      bYellow = True
                      rw(1, icol) = cell.Offset(, icol + 1).Value
                  End If
                Next icol
                If bYellow Then
                  f.Offset(1).EntireRow.Insert
                  With f.Offset(1, 2).Resize(, cols)
                    .Value = rw
                    .SpecialCells(xlConstants).Interior.ColorIndex = 6
                  End With
                  nr = nr + 1
                End If
            End If
        Next cell
    End With
    Range("A1").Select
End Sub
 
Upvote 0

Forum statistics

Threads
1,221,310
Messages
6,159,173
Members
451,543
Latest member
cesymcox

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