Comparing items between two data sets

Dylan7

New Member
Joined
Jun 27, 2014
Messages
8
Thank you for taking a look at my issue. It is a little long but I have tried to explain it as concisely as possible and will be happy to answer any questions. The included example data shows what i would like the end result to look like. I am using windows 7, Excel 2010.</SPAN>

I am looking to search the column “name” in Data Set(2) for a name from Data Set(1) to find a match. If there is a match I want to compare the associated Date from Data Set(1) to the Date in DataSet(2) and if Date(2)>Date(1) then output text "Success" in the results column.</SPAN>
If Date(2)>Date(1) is not true, then continue searching Data Set(2) for the name again until another match is made and then repeat the date test and so on until both the name and date tests are true.
I would like to do this for every name in Data Set(1)
</SPAN>

The current manual process I do right now is.</SPAN>

  1. Copy Name from Data Set(1) </SPAN>
  2. Find (Ctrl F) in Data Set(2) for the name</SPAN>
  3. Manually determine if Date(2)>Date(1)</SPAN>
    1. If Date(2)>Date(1) is not true</SPAN>
      1. Repeat Step 2 and exclude name that was just tested</SPAN>
      2. Repeat Step 3 </SPAN>
    2. If Date(2)>Date(1) is true, Type “Success” in results column
</SPAN>
Thank you to everyone again for your time if you made it this far. I have tried a few formuals to absolutly no avail so far. I get the feeling this will need to be done in Visual Basic which i am not very good at writing in but am good at editing in.


Example Data
Data Set(1)
Data Set(2)
Results
Name
Date
Name
Date
1112A
11/1/2014
1112A
10/29/2014
1113A
12/1/2014
1105C
12/26/2014
1114B
1/5/2015
1109B
3/4/2015
1114B
11/20/2014
1113A
10/21/2014
1114A
2/6/2015
1112A
11/7/2014
Success
1115C
6/15/2015
111D
6/1/2015
1111C
11/20/2014
1315A
10/2/2014
1112B
12/11/2014
1114B
10/1/2014
1117A
5/1/2015
1114B
11/25/2014
Success
1114B
2/1/2015
Success
1113A
8/12/2014
1114A
2/1/2015
1116B
8/1/2015
1115C
7/1/2015
Success
1111C
11/27/2014
Success
1114A
2/12/2015
Success
1112B
3/10/2015
Success
1113A
2/25/2015
Success

<TBODY>
</TBODY>
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
First of all I'd like to thank you for taking the time to be thorough in your explination as well as provide a sample dataset for me to view. I can't tell you how annoying it is when people don't do that. Now as for your two datasets, you did not specify if they are on different worksheets, so I'm going to assume that they are. Here is the code that I wrote directly from my mind. It is untested.
Code:
Sub myMacro()
    sht1 = "Sheet1"
    sht2 = "Sheet2"  [COLOR=#006400]'This one is where the results will go.[/COLOR]
    lastRow1 = Sheets(sht1).Range("A" & Rows.Count).End(xlup).Row
    lastRow2 = Sheets(sht2).Range("A" & Rows.Count).End(xlup).Row
    Sheets(sht2).Range("C2:C" & lastRow2).ClearContents  [COLOR=#006400]'might be ClearContent without the s[/COLOR]

    i = 2
    Do Until i > lastRow2
        ii = 2
        Do Until ii > lastRow1
            If Sheets(sht2).Range("A" & i).Value = Sheets(sht1).Range("A" & ii).Value AND _
                Sheets(sht2).Range("B" & i).Value > Sheets(sht1).Range("B" & ii).Value Then
                Sheets(sht2).Range("C" & i).Value = "Success"
            End If
            ii = ii + 1
        Loop
        i = i + 1
    Loop
End Sub
Take note that the code says i = 2 and ii = 2. I am assuming that the first value in your dataset 1112A is located at cell A2. If it is located in cell A3, then change 2 to 3 in both instances of the code. These are the starting points of the loops. I enjoy answering these nested loop questions because not a lot of people answer them. It's not difficult if you have enough experience doing them. You just need to imagine running through the code line by line in your head. Anyways what you asked for was very easy and I hope it works for you.
 
Upvote 0
Dylan7,

Sample raw data worksheets:


Excel 2007
AB
1NameDate
21112A11/1/2014
31113A12/1/2014
41114B1/5/2015
51114B11/20/2014
61114A2/6/2015
71115C6/15/2015
81111C11/20/2014
91112B12/11/2014
10
Data Set(1)



Excel 2007
ABC
1NameDate
21112A10/29/2014
31105C12/26/2014
41109B3/4/2015
51113A10/21/2014
61112A11/7/2014
7111D6/1/2015
81315A10/2/2014
91114B10/1/2014
101117A5/1/2015
111114B11/25/2014
121114B2/1/2015
131113A8/12/2014
141114A2/1/2015
151116B8/1/2015
161115C7/1/2015
171111C11/27/2014
181114A2/12/2015
191112B3/10/2015
201113A2/25/2015
21
Data Set(2)


After the macro in worksheet Data Set(2):


Excel 2007
ABC
1NameDate
21112A10/29/2014
31105C12/26/2014
41109B3/4/2015
51113A10/21/2014
61112A11/7/2014Success
7111D6/1/2015
81315A10/2/2014
91114B10/1/2014
101117A5/1/2015
111114B11/25/2014Success
121114B2/1/2015Success
131113A8/12/2014
141114A2/1/2015
151116B8/1/2015
161115C7/1/2015Success
171111C11/27/2014Success
181114A2/12/2015Success
191112B3/10/2015Success
201113A2/25/2015Success
21
Data Set(2)


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub FindSuccess()
' hiker95, 10/13/2014, ME811455
Dim w1 As Worksheet, w2 As Worksheet
Dim c As Range, a As Range
Dim lr As Long, n As Long, i As Long, sr As Long
Application.ScreenUpdating = False
Set w1 = Sheets("Data Set(1)")
Set w2 = Sheets("Data Set(2)")
w2.Columns(3).ClearContents
lr = w2.Cells(Rows.Count, 1).End(xlUp).Row
With w1
  For Each c In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
    n = Application.CountIf(w2.Columns(1), c.Value)
    sr = 1
    If n > 0 Then
      For i = 1 To n
        Set a = w2.Range("A" & sr & ":A" & lr).Find(c.Value, LookAt:=xlWhole)
        If Not a Is Nothing Then
          If w2.Cells(a.Row, 2).Value > .Cells(c.Row, 2).Value Then
            w2.Cells(a.Row, 3).Value = "Success"
          End If
        End If
        sr = a.Row + 1
        Set a = Nothing
      Next i
    End If
  Next c
End With
With w2
  .Columns(3).AutoFit
  .Activate
End With
Application.ScreenUpdating = True
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm

Then run the FindSuccess macro.
 
Upvote 0
Dylan7,

With the same screenshots as my reply #3, the following macro is much faster using three arrays in memory.

Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

Code:
Sub FindSuccessV2()
' hiker95, 10/13/2014, ME811455
Dim a As Variant, b As Variant, o As Variant
Dim i As Long, j As Long
Dim lra As Long, lrb As Long
With Sheets("Data Set(1)")
  lra = .Cells(Rows.Count, 1).End(xlUp).Row
  a = .Range("A1:B" & lra)
End With
With Sheets("Data Set(2)")
  lrb = .Cells(Rows.Count, 1).End(xlUp).Row
  b = .Range("A1:B" & lrb)
  ReDim o(1 To lrb, 1 To 1)
End With
For i = 2 To lra
  For j = 2 To lrb
    If a(i, 1) = b(j, 1) Then
      If b(j, 2) > a(i, 2) Then
        o(j, 1) = "Success"
      End If
    End If
  Next j
Next i
With Sheets("Data Set(2)")
  .Cells(1, 3).Resize(lrb) = o
  .Columns(3).AutoFit
  .Activate
End With
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm

Then run the FindSuccessV2 macro.
 
Upvote 0
Thanks WarPiglet, that program worked perfectly. I really appreciate your help. hiker95, i didnt try your program because the other one worked but thank you for spending time on my question also. This is a fantastic community that always amazes me with the level of support.
 
Upvote 0
Dylan7,

hiker95, i didnt try your program because the other one worked but thank you for spending time on my question also.

Thanks for the feedback.

You are very welcome.


You may be surprised by the speed of my second macro, FindSuccessV2, because it uses three arrays in memory.


And, come back anytime.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,406
Messages
6,124,720
Members
449,184
Latest member
COrmerod

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