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
 
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

A moment of inattention, sorry about that...

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

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

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Hi Peter,

Thanks for your help. I have got almost everything to work. But now i experience that we have several unique values for different years. So for example i want to know all unique customers in september, but only for 2018 not 2017. Is it possible to include 2 differnet If formulas in the original formula? I have not got it to work.

Easy example:
Year Month Name
2017 September Mr Pink
2018 September John Doe
2018 September John Doe
2018 September Mr Black

The result i would like to get is that for 2018 we have 2 unique customers (John Doe and Mr Black) but it does not include the 2017 customer even though it is a unique customer in September (although 2017).

Hope you understand what i mean.

Best regards
Agatonsaxx
 
Upvote 0
[...]Easy example:
Year Month Name
2017 September Mr Pink
2018 September John Doe
2018 September John Doe
2018 September Mr Black

The result i would like to get is that for 2018 we have 2 unique customers (John Doe and Mr Black) but it does not include the 2017 customer even though it is a unique customer in September (although 2017).

[…]

What is the expected count?
 
Upvote 0
Hi Aladin,

Well what do you mean with expected count?

I have a list with over 2000 customers from both 2016, 2017, 2018. I have columns showing what salesperson met the customer and what month and week.
Sometimes we have a customer that meets the same salesperson but for 3 different companies.

What i would like to do then is to register the customer 3 times and show in a report that during week 37 employeX had 13 customers, but only 9 unique customers (since 2 of the customermeetings occured with the same customers).

CustomerMonthWeekSalespersonCompany
John DoeJanuary1ChristianCompany X
John DoeJanuary1ChristianCompany Y
Mr BlackJanuary2ChristianCompany X
Mr PinkFebruary5ChristianCompany X
Mr BlackMarch8ChristianCompany Z
Mr SweetMarch9ChristianCompany X

<tbody>
</tbody>

From this table i would like to be able to get the following result when:

Reporting Christians total meetings and unique meetings during:
Week 1: 2 total, 1 unique
Month January: 3 total, 2 unique

I have been able to report unique values for a month and a week. But when i try to add another variable (in this case Christian) i do not know how to move forward.

Best regards
Agatonsaxx
 
Upvote 0
Hi again, i will try to be as clear as i can sorry for making this so difficult to explain.

I have a table with the following values:

YearMonthWeekCustomerSalesperson
2017January1Mr BlackChristian
2018January1Mr BlackChristian
2018January1Mr PinkChristian
2018January1Mr WhiteChristian
2018January1Mr PurpleChristian
2018January1Mr RedChristian
2018January1Mr BlueChristian
2018January1Mr GreenChristian
2018January1Mr BlackChristian

<tbody>
</tbody>

In this case we have a total of 9 customers in January (1 in 2017, 8 in 2018).

We also have a duplicate customer (Mr Black), which means that in my report i would like it to reflect:

Meetings for Christian during Week 1 in January: 8 total customers, 7 unique customers

The issue i have been experiencing is not to find unique values (you have already helped me with that issue). The problem i have now is that we have several variables (Year, Month, Salesperson) or (Year, Week, Salesperson). Before we only sorted the values based on a Month or a Week and then looked for the unique customer names. Now i would like to include the variable Year and also variable Salesperson.

Is this even possible?

Thanks in advance,

Best regards
Agatonsaxx
 
Upvote 0

Book1
ABCDEFGHIJKL
1YearMonthWeekCustomerSalespersonSPYEARMONTHWEEK# records# customers
22017January1Mr BlackChristianchristian2018january187
32018January1Mr BlackChristian
42018January1Mr PinkChristian
52018January1Mr WhiteChristian
62018January1Mr PurpleChristian
72018January1Mr RedChristian
82018January1Mr BlueChristian
92018January1Mr GreenChristian
102018January1Mr BlackChristian
Sheet2


In K2 just enter:

=COUNTIFS($A$2:$A$10,H2,$B$2:$B$10,I2,$C$2:$C$10,1,$E$2:$E$10,G2)

In L2 control+shift+enter, not just enter:

=SUM(IF(FREQUENCY(IF(($D$2:$D$10<>"")*($A$2:$A$10=H2)*($B$2:$B$10=I2)*($C$2:$C$10=J2)*($E$2:$E$10=G2),MATCH($D$2:$D$10,$D$2:$D$10,0)),ROW($A$2:$E$10)-ROW(INDEX($A$2:$E$10,1,1))+1),1))
 
Upvote 0
Thank you Aladin! This solved my issue and was clearly explained!

Thank both Peter and Aladin for your help with this. I really appreciate it!

Best regards
Agatonsaxx
 
Upvote 0
Hi again Aladin.

I have found another issue related to this post. You might be able to help me with this one (since both you and Peter have been very helpful in the past).

My issue is as follows:
I have a list of customers that all have got different offerings from me. I need to know the unique values per customer depending on a status. But what i have been experiencing now, is that it will always fetch the value from the cell that is "first" in the list, no matter if the status is different.

Example:

CustomerMonthOfferingStatus
John DoeSeptember10 000Not active
John DoeSeptember12 000Active
Mr BlackSeptember15 000Active

<tbody>
</tbody>

What i would like to be able to do. Is to have a formula that looks inside the table and are able to find out that in September we have active offerings on the market for 27 000 (and not 25 000). Right now, my formula will look at the unique values on customer and then return the first value for John Doe (even though he is inactive). I have used your formula to try and get this to work.

Do you have any suggestions on how to solve this?

Best regards
Agatonsaxx
 
Upvote 0
@ agatonsaxxI have found another issue related to this post. You might be able to help me with this one (since both you and Peter have been very helpful in the past).

[…]

Example:

CustomerMonthOfferingStatus
John DoeSeptember10 000Not active
John DoeSeptember12 000Active
Mr BlackSeptember15 000Active

<tbody>
</tbody>

[…]


Care to state this new question in terms of the example data you posted? If you would, what is the expected result?
 
Upvote 0

Forum statistics

Threads
1,214,599
Messages
6,120,447
Members
448,966
Latest member
DannyC96

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