Find nth Unique Value

4653

New Member
Joined
Apr 20, 2012
Messages
27
Office Version
  1. 365
Platform
  1. Windows
I'm looking for a formula that can do one of two things. Ultimately I don't care which one it does because I can make either of them work but if I had my preference I would prefer something like Solution 1.
I have two worksheets (let's call them SheetA and SheetB) each with the same headers, First, Last Cell, Email and Street in row 1 columns A-E

Solution 1:
I would like something that I can place the formula in A2, B2, C2, D2 and E2 on SheetC, that will look in Columns C, D and E rows 1-5000 on SheetA and compare it to Columns C, D and E rows 1-5000 on SheetB and return the nth unique row from SheetA where C, D and E on SheetA can't be found in C, D and E on SheetB. C, D and E would have to all 3 be found on the same row on SheetB, otherwise if just C and D were found but E didn't match, it would still recognize that as a unique row on SheetA and be pulled into Sheet C.

For Instance:
SheetA
FirstLastCellEmailStreet
GregPearson444-123-4567greg@fake.com123 Fake Pl
ChrisSmith444-456-4568chris@fake.com467 Lost Cir
JeffToler444-982-4569jeff@fake.com4591 Orlando Rd
JasonCassidy444-734-4570jason@fake.com13456 Bike St
DanFoster444-467-4571dan@fake.com1242 Found Pl

SheetB
FirstLastCellEmailStreet
GregPearson444-123-4567greg@fake.com123 Fake Pl
JeffToler444-982-4569jeff@fake.com4591 Orlando Rd
DanFoster444-467-4571dan@fake.com1242 Found Pl

SheetC
FirstLastCellEmailStreet
ChrisSmith444-456-4568chris@fake.com467 Lost Cir
JasonCassidy444-734-4570jason@fake.com13456 Bike St

Solution 2:
The alternative would be a formula that does the exact same thing but just looks at one Column, say for instance Column C, instead of looking at all 3 Columns C, D and E at the same time.
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
How about
+Fluff 1.xlsm
ABCDE
1FirstLastCellEmailStreet
2GregPearson444-123-4567greg@fake.com123 Fake Pl
3ChrisSmith444-456-4568chris@fake.com467 Lost Cir
4ChrisSmith444-456-4568chris@fake.com467 Lost Cir
5JeffToler444-982-4569jeff@fake.com4591 Orlando Rd
6JasonCassidy444-734-4570jason@fake.com13456 Bike St
7DanFoster444-467-4571dan@fake.com1242 Found Pl
8
Sheet1


+Fluff 1.xlsm
ABCDE
1FirstLastCellEmailStreet
2GregPearson444-123-4567greg@fake.com123 Fake Pl
3JeffToler444-982-4569jeff@fake.com4591 Orlando Rd
4DanFoster444-467-4571dan@fake.com124 Found Pl
5
Sheet2


+Fluff 1.xlsm
ABCDE
1FirstLastCellEmailStreet
2ChrisSmith444-456-4568chris@fake.com467 Lost Cir
3JasonCassidy444-734-4570jason@fake.com13456 Bike St
4DanFoster444-467-4571dan@fake.com1242 Found Pl
5
Sheet3
Cell Formulas
RangeFormula
A2:E4A2=UNIQUE(FILTER(Sheet1!A2:E11,((ISNA(MATCH(Sheet1!C2:C11,Sheet2!C2:C11,0)))+(ISNA(MATCH(Sheet1!D2:D11,Sheet2!D2:D11,0)))+(ISNA(MATCH(Sheet1!E2:E11,Sheet2!E2:E11,0))))*(Sheet1!A2:A11<>"")))
Dynamic array formulas.
 
Upvote 0
Solution
How about
+Fluff 1.xlsm
ABCDE
1FirstLastCellEmailStreet
2GregPearson444-123-4567greg@fake.com123 Fake Pl
3ChrisSmith444-456-4568chris@fake.com467 Lost Cir
4ChrisSmith444-456-4568chris@fake.com467 Lost Cir
5JeffToler444-982-4569jeff@fake.com4591 Orlando Rd
6JasonCassidy444-734-4570jason@fake.com13456 Bike St
7DanFoster444-467-4571dan@fake.com1242 Found Pl
8
Sheet1


+Fluff 1.xlsm
ABCDE
1FirstLastCellEmailStreet
2GregPearson444-123-4567greg@fake.com123 Fake Pl
3JeffToler444-982-4569jeff@fake.com4591 Orlando Rd
4DanFoster444-467-4571dan@fake.com124 Found Pl
5
Sheet2


+Fluff 1.xlsm
ABCDE
1FirstLastCellEmailStreet
2ChrisSmith444-456-4568chris@fake.com467 Lost Cir
3JasonCassidy444-734-4570jason@fake.com13456 Bike St
4DanFoster444-467-4571dan@fake.com1242 Found Pl
5
Sheet3
Cell Formulas
RangeFormula
A2:E4A2=UNIQUE(FILTER(Sheet1!A2:E11,((ISNA(MATCH(Sheet1!C2:C11,Sheet2!C2:C11,0)))+(ISNA(MATCH(Sheet1!D2:D11,Sheet2!D2:D11,0)))+(ISNA(MATCH(Sheet1!E2:E11,Sheet2!E2:E11,0))))*(Sheet1!A2:A11<>"")))
Dynamic array formulas.
Thank you so much! This works perfectly.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,224,822
Messages
6,181,165
Members
453,021
Latest member
Justyna P

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