Assistance needed in amending a macro.

ghrek

Active Member
Joined
Jul 29, 2005
Messages
427
Hi

I had this macro that compared data between sheets 1 and 2 and marked "OK" "MISSING" and "DUPLICATE"

What im trying to amend it to do is to mark "OK" and "DUPLICATE" on sheet 1 still but when data is on sheet 2 but not on sheet 1 I need it marked "MISSING" on the row concerned on sheet 2.

Any ideas on how I can do this?


Sub compare_data()
Dim sh1 As Worksheet, sh2 As Worksheet
Dim i As Long, j As Long, lr As Long

Set sh1 = ActiveWorkbook.Sheets("Sheet1")
Set sh2 = ActiveWorkbook.Sheets("Sheet2")

Application.ScreenUpdating = False
lr = sh1.Range("A" & sh1.Rows.Count).End(xlUp).Row
For i = 2 To lr
Application.StatusBar = "Checking row : " & i & " of : " & lr
j = Application.CountIfs(sh2.Columns("A"), sh1.Cells(i, "A").Value, sh2.Columns("B"), sh1.Cells(i, "B").Value, sh2.Columns("C"), sh1.Cells(i, "C").Value, _
sh2.Columns("D"), sh1.Cells(i, "D").Value)
Select Case j
Case 0
sh1.Cells(i, "E").Value = "MISSING"
Case 1
sh1.Cells(i, "E").Value = "OK"
Case Is > 1
sh1.Cells(i, "E").Value = "DUPLICATE"
End Select
Next
MsgBox "Done"
End Sub

Thanks
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
Now you need to look for each data of sheet2 on sheet1.

Try this:

Code:
Sub compare_data()
  Dim sh1 As Worksheet, sh2 As Worksheet
  Dim i As Long, j As Long, lr As Long
  
  Set sh1 = ActiveWorkbook.Sheets("Sheet1")
  Set sh2 = ActiveWorkbook.Sheets("Sheet2")
  
  Application.ScreenUpdating = False
  Application.StatusBar = False
  lr = sh1.Range("A" & sh1.Rows.Count).End(xlUp).Row
  'Search 1 in 2
  For i = 2 To lr
    Application.StatusBar = "Checking row : " & i & " of : " & lr
    j = Application.CountIfs(sh2.Columns("A"), sh1.Cells(i, "A").Value, sh2.Columns("B"), sh1.Cells(i, "B").Value, sh2.Columns("C"), sh1.Cells(i, "C").Value, _
    sh2.Columns("D"), sh1.Cells(i, "D").Value)
    Select Case j
      Case 0
      sh1.Cells(i, "E").Value = "MISSING"
      Case 1
      sh1.Cells(i, "E").Value = "OK"
      Case Is > 1
      sh1.Cells(i, "E").Value = "DUPLICATE"
    End Select
  Next
  '
[COLOR=#008000]  'Search 2 in 1[/COLOR]
[COLOR=#0000ff]  lr = sh2.Range("A" & sh1.Rows.Count).End(xlUp).Row[/COLOR]
[COLOR=#0000ff]  For i = 2 To lr[/COLOR]
[COLOR=#0000ff]    Application.StatusBar = "Checking row : " & i & " of : " & lr[/COLOR]
[COLOR=#0000ff]    j = Application.CountIfs(sh1.Columns("A"), sh2.Cells(i, "A").Value, sh1.Columns("B"), sh2.Cells(i, "B").Value, _[/COLOR]
[COLOR=#0000ff]      sh1.Columns("C"), sh2.Cells(i, "C").Value, sh1.Columns("D"), sh2.Cells(i, "D").Value)[/COLOR]
[COLOR=#0000ff]    Select Case j[/COLOR]
[COLOR=#0000ff]      Case 0[/COLOR]
[COLOR=#0000ff]      sh2.Cells(i, "E").Value = "MISSING"[/COLOR]
[COLOR=#0000ff]    End Select[/COLOR]
[COLOR=#0000ff]  Next[/COLOR]
  MsgBox "Done"
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,885
Messages
6,175,187
Members
452,616
Latest member
intern444

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