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

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
You are welcome. Thanks for the confirmation. :)
Hi Peter. I've been advised that occasionally there is a Sheet3 added to the Workbook in the same format as the other sheets.
How can I adjust the above code to compare Sheet3 with Sheet2 then insert the variances into a new corresponding row in Sheet1 below the new rows already created by running your Changes_V3 sub.
This will be run as a separate sub to the above Changes_V3 as there is not always a Sheet3.
 
Upvote 0
Could we have a small sample of all 3 sheets (Sheet1 & Sheet2 should be after the previous v3 code has been run but before this new code has been run). Then another of what Sheet1 should look like after this new code. Add any further explanation in relation to the samples.
 
Upvote 0
Hi Peter
Using the same data set as above after running the V3 the sheets1 & 2 look like this (This is perfect and works great).

Sheet1
2024-08-22_10-47-21.jpg


Sheet2
2024-08-22_10-47-52.jpg


Sheet3 is then added to the Workbook (see data set below).
The new code needs to compare Sheet3 with Sheet2 and highlight the variations on Sheet3 in Blue (see example screen shot below), and then insert "Blue" cells below the corresponding ID row in Sheet1 (see example below).

Sheet3 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
11128SC14:00-22:0014:00-22:0014:00-22:00DAY OFF14: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
13328SC22:00-06:0022:00-06:0022:00-06:00DAY OFFDAY OFF06:00-14:0006:00-14:00

After running new code Sheet3 will look like this
2024-08-22_11-12-46.jpg


And Sheet1 will now look like this
2024-08-22_11-14-37.jpg


Thanks for your help.
 
Upvote 0
Thanks for the samples.
Is it possible that an ID on Sheet3 does not appear on Sheet2 like the red rows in the earlier code when we compared Sheet2 to Sheet1? If so, what should happen?
 
Upvote 0
I don't understand row 8 of your final Sheet1 image. Why is H8 14:00-22:00 when Saturday for ID 12649 on Sheet3 is 06:00-14:00 which is the same as Saturday for ID 12649 on Sheet2?
Sheet3 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
11128SC14:00-22:0014:00-22:0014:00-22:00DAY OFF14: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
13328SC22:00-06:0022:00-06:0022:00-06:00DAY OFFDAY OFF06:00-14:0006:00-14:00

1724330502665.png
 
Upvote 0
Sorry Peter... There was 2 errors in the Sheet3 data I provided. (ID 12649 Column H & ID12880 Column I)
This one should be accurate.
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
11128SC14:00-22:0014:00-22:0014:00-22:00DAY OFF14: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:0014:00-22: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 OFF06:00-14:00
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
This one should be accurate.
Thanks.
The code does not check so is relying on the following being accurate ..
all ID's should match Sheet2 & Sheet3
If there is an ID on Sheet3 that is not on Sheet2 the code will error (& need amending)

Try this
VBA Code:
Sub Check_Sheet3_vs_Sheet2()
  Dim rw As Variant
  Dim fSh2 As Range, fSh1 As Range, cell As Range
  Dim icol As Long, cols As Long, oSet As Long
  Dim bBlue As Boolean
  
  With Worksheets("Sheet3")
    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))
      bBlue = False
      Set fSh2 = Sheets("Sheet2").Columns("A").Find(What:=cell.Value, LookIn:=xlValues, LookAt:=xlWhole)
      For icol = 1 To cols
        rw(1, icol) = vbNullString
        If fSh2.Offset(, icol + 1).Value <> cell.Offset(, icol + 1).Value Then
          cell.Offset(, icol + 1).Interior.ColorIndex = 33
          bBlue = True
          rw(1, icol) = cell.Offset(, icol + 1).Value
        End If
      Next icol
      If bBlue Then
        Set fSh1 = Sheets("Sheet1").Columns("A").Find(What:=cell.Value, LookIn:=xlValues, LookAt:=xlWhole)
        oSet = 1 - IsEmpty(fSh1.Offset(1).Value)
        fSh1.Offset(oSet).EntireRow.Insert
        With fSh1.Offset(oSet, 2).Resize(, cols)
          .Interior.ColorIndex = 0
          .Value = rw
          .SpecialCells(xlConstants).Interior.ColorIndex = 33
        End With
      End If
    Next cell
  End With
End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,224,748
Messages
6,180,721
Members
452,995
Latest member
isldboy

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