Lookup unique values from two different columns

agatonsaxx

New Member
Joined
May 29, 2014
Messages
34
Hi everyone,

I would like to be able to summarize unique values from two different columns. Here is my example:

Column A (Month) | Column B (Name)
January John Doe
January John Doe
January Clark Kent
February Clark Kent
February Mr Black
April Mr Black
April Mr Black

What i would like to be able to do, is to write a formula that can look inside the two columns and sort out the unique values of the name based on in which month the name occured.

In this case i would like it to show:

Unique customers in january: 2 (John Doe + Clark Kent)
Unique customers in februari 2 (Clark Kent + Mr Black)
Unique customers in April 1 (Mr Black)

I have the following formula that only looks in the Name column and gives me the correct value, but it looks on all the values, instead of including the month criteria.

[FONT=&quot]=SUM(IF(FREQUENCY(IF(LEN(A2:A10)>0,MATCH(A2:A10,A2:A10,0),""), IF(LEN(A2:A10)>0,MATCH(A2:A10,A2:A10,0),""))>0,1))

[/FONT]
Can somebody please help me with this or say if it is possible in any way?

Best regards
AgatonSaxx
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Like this, copied across and down?

Excel Workbook
ABCDE
1
2JanuaryJohn DoeJanuaryJohn Doe
3JanuaryJohn DoeJanuaryClark Kent
4JanuaryClark KentFebruaryClark Kent
5FebruaryClark KentFebruaryMr Black
6FebruaryMr BlackAprilMr Black
7AprilMr Black
8AprilMr Black
Unique 2 Cols
 
Upvote 0
Hi Peter, thanks for your answer.

I do not really get this to work. I don't fully understand what you have done.

Cell D and E, is that where you actually put the formula? Because when i try to insert the formula, it only returns a blank value.

What i would like to return is something like:

Unique customers in January: 2
Unique customers in February: 1
etc.

Do you understand how i mean?

Thanks in advance,

Best regards
AgatonSaxx

Like this, copied across and down?

Unique 2 Cols

ABCDE
1
2JanuaryJohn Doe JanuaryJohn Doe
3JanuaryJohn Doe JanuaryClark Kent
4JanuaryClark Kent FebruaryClark Kent
5FebruaryClark Kent FebruaryMr Black
6FebruaryMr Black AprilMr Black
7AprilMr Black
8AprilMr Black

<colgroup><col style="font-weight:bold; width:30px; "><col style="width:88px;"><col style="width:80px;"><col style="width:17px;"><col style="width:103px;"><col style="width:109px;"></colgroup><tbody>
</tbody>

Spreadsheet Formulas
CellFormula
D2=IFERROR(INDEX(A$2:A$8,AGGREGATE(15,6,(ROW(A$2:A$8)-ROW(A$2)+1)/(ROW(A$2:A$8)-ROW(A$2)+1=MATCH($A$2:$A$8&"|"&$B$2:$B$8,INDEX($A$2:$A$8&"|"&$B$2:$B$8,0),0)),ROWS(D$2:D2))),"")

<tbody>
</tbody>

<tbody>
</tbody>


Excel tables to the web >> Excel Jeanie HTML 4
 
Upvote 0

Book1
ABCDEFG
1JanuaryFebruaryApril
2JanuaryJohn DoeJohn DoeClark KentMr Black
3JanuaryJohn DoeClark KentMr Black
4JanuaryClark Kent
5FebruaryClark Kent
6FebruaryMr Black
7AprilMr Black
8AprilMr Black
Sheet1


In D1 control+shift+enter, not just enter, copy across.

=IFERROR(INDEX($A$2:$A$8,SMALL(IF(FREQUENCY(IF($A$2:$A$8<>"",MATCH($A$2:$A$8,$A$2:$A$8,0)),ROW($A$2:$B$8)-ROW(INDEX($A$2:$B$8,1,1))+1),ROW($A$2:$B$8)-ROW(INDEX($A$2:$B$8,1,1))+1),COLUMNS($D$1:D1))),"")

In D2 control+shift+enter, not just enter, copy across, and down:

=IFERROR(INDEX($B$2:$B$8,SMALL(IF(FREQUENCY(IF($B$2:$B$8<>"",IF($A$2:$A$8=D$1,MATCH($B$2:$B$8,$B$2:$B$8,0))),ROW($A$2:$B$8)-ROW(INDEX($A$2:$B$8,1,1))+1),ROW($A$2:$B$8)-ROW(INDEX($A$2:$B$8,1,1))+1),ROWS(D$2:D2))),"")

If interested only in counts...

In D2 control+shift+enter, not just enter, and copy across:

=IF(D$1="","",SUM(IF(FREQUENCY(IF($B$2:$B$8<>"",IF($A$2:$A$8=D$1,MATCH($B$2:$B$8,$B$2:$B$8,0))),ROW($A$2:$B$8)-ROW(INDEX($A$2:$B$8,1,1))+1),1)))
 
Last edited:
Upvote 0
You can try PivotTable with DataModel


MonthNameMonthName
JanuaryJohn DoeAprilMr Black
JanuaryJohn DoeFebruaryClark Kent
JanuaryClark KentMr Black
FebruaryClark KentJanuaryClark Kent
FebruaryMr BlackJohn Doe
AprilMr Black
AprilMr Black
 
Upvote 0
What i would like to return is something like:

Unique customers in January: 2
Unique customers in February: 1
etc.
Sorry, I misinterpreted your original request. Try these formulas, copied down. The E2 formula is an array formula so should be entered without the {} but confirmed with Ctrl+Shift+Enter, not just Enter. If confirmed correctly, Excel will insert the {}. The formula can then be copied down.

Excel Workbook
ABCDE
1MonthNameMonthCount
2JanuaryJohn DoeJanuary2
3JanuaryJohn DoeFebruary2
4JanuaryClark KentApril1
5FebruaryClark Kent
6FebruaryMr Black
7AprilMr Black
8AprilMr Black
Unique 2 Cols
 
Upvote 0
Hi Peter thanks for your answer. From what i can see, this will solve my issue!

I have another question on the same topic. This is a bit more complex i think.

Scenario:

We have a customer that has recieved 3 different offerings (quotes) from us. We want to keep track of this in our salessystem but we do not want the offering (values) to be trippled.

Example:

Month | Name | Value
January | John Doe | 1000
January | John Doe | 2000
January | Clark Kent | 3000
February | Clark Kent | 2000

What we would like this to reflect is:
Possible sales in january: 4000 (not 6000)
Possible sales in february: 2000 (even though Clark Kent got an offer in january)

Do you have any suggestions on how this would be possible?

Thanks in advance,

Best regards
Agatonsaxx
 
Upvote 0
Hi Peter thanks for your answer. From what i can see, this will solve my issue!

What I offered solves your issue too.

I have another question on the same topic. This is a bit more complex i think.

Scenario:

We have a customer that has recieved 3 different offerings (quotes) from us. We want to keep track of this in our salessystem but we do not want the offering (values) to be trippled.

Example:

Month | Name | Value
January | John Doe | 1000
January | John Doe | 2000
January | Clark Kent | 3000
February | Clark Kent | 2000

What we would like this to reflect is:
Possible sales in january: 4000 (not 6000)
Possible sales in february: 2000 (even though Clark Kent got an offer in january)

Do you have any suggestions on how this would be possible?

Thanks in advance,

Best regards
Agatonsaxx



Book1
ABCDEF
1MonthNameValue
2JanuaryJohn Doe1000January4000
3JanuaryJohn Doe2000February3000
4JanuaryClark Kent3000
5FebruaryClark Kent2000
6
Sheet2


In E2 control+shift+enter, not just enter, and copy down:

=IFERROR(INDEX($A$2:$A$5,SMALL(IF(FREQUENCY(IF($A$2:$A$5<>"",MATCH($A$2:$A$5,$A$2:$A$5,0)),ROW($A$2:$C$5)-ROW(INDEX($A$2:$C$5,1,1))+1),ROW($A$2:$C$5)-ROW(INDEX($A$2:$C$5,1,1))+1),ROWS($E$2:E2))),"")

In F2 control+shift+enter, not just enter, and copy down:

=IF($E2="","",SUM(IF(FREQUENCY(IF($A$2:$A$5=$E2,MATCH($B$2:$B$5,$B$2:$B$5,0)),ROW($A$2:$C$5)-ROW(INDEX($A$2:$C$5,1,1))+1),$C$2:$C$5)))
 
Upvote 0
What I offered solves your issue too.




ABCDEF
1Month Name Value
2JanuaryJohn Doe 1000January4000
3JanuaryJohn Doe 2000February3000
4JanuaryClark Kent 3000
5FebruaryClark Kent 2000
6

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet2

In E2 control+shift+enter, not just enter, and copy down:

=IFERROR(INDEX($A$2:$A$5,SMALL(IF(FREQUENCY(IF($A$2:$A$5<>"",MATCH($A$2:$A$5,$A$2:$A$5,0)),ROW($A$2:$C$5)-ROW(INDEX($A$2:$C$5,1,1))+1),ROW($A$2:$C$5)-ROW(INDEX($A$2:$C$5,1,1))+1),ROWS($E$2:E2))),"")

In F2 control+shift+enter, not just enter, and copy down:

=IF($E2="","",SUM(IF(FREQUENCY(IF($A$2:$A$5=$E2,MATCH($B$2:$B$5,$B$2:$B$5,0)),ROW($A$2:$C$5)-ROW(INDEX($A$2:$C$5,1,1))+1),$C$2:$C$5)))

Hi Peter,

It looks like it works for january, but it gets summarized wrong in february (it says 3000 instead of 2000), do you know why?

Best regards
Agatonsaxx
 
Upvote 0
Hi Peter thanks for your answer. From what i can see, this will solve my issue!
You are welcome.

Hi Peter,

It looks like it works for january, ..
I think you meant "Hi Aladin" ;)

Also, best not to fully quote long posts as it makes the thread harder to read/navigate. If you want to quote, quote small, relevant parts only.

See if this does what you want. If not, please explain why in your example in post 7, the expected value for January is 4000 (1000 for John Doe + 3000 for Clark Kent) and not 5000 (2000 for John Doe + 3000 for Clark Kent)

Excel Workbook
ABCDEF
1MonthNameValueMonthValue
2JanuaryJohn Doe1000January4000
3JanuaryJohn Doe2000February2000
4JanuaryClark Kent3000
5FebruaryClark Kent2000
Unique 2 Cols (2)
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,007
Messages
6,122,670
Members
449,091
Latest member
peppernaut

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