Fromula to Count Number of Unequie Values

Browneh89

Board Regular
Joined
Mar 8, 2019
Messages
55
Office Version
  1. 365
Platform
  1. Windows
Hello, I am attempting to find a formula which counts the number of unique values in a table attached to a certain ID.

I attempted a formula like this one below (this formula is not for the table below it was just the example I was working with)

=SUM(IF("Tom"=$C$2:$C$20, 1/(COUNTIFS($C$2:$C$20, "Tom", $A$2:$A$20, $A$2:$A$20)), 0))

However it overloaded my excel because the table I'm looking at has over 2000 rows of data.

Are there any other ways or formulas to achieve the result show below. (Below I'm using a simplified version of the table I'm using)

Basically I'm looking to be able to find the number of unique route values for certain ID's in another table.

1611077827909.png


Thank you for any help!
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
How about
Excel Formula:
=COUNT(UNIQUE(FILTER(B2:B100,C2:C100=H2)))
 
Upvote 0
Possibly:

Book1
HI
1IDUnique Route Count
288492
355963
444871
Sheet1
Cell Formulas
RangeFormula
H2:H4H2=UNIQUE(C2:C10)
I2:I4I2=COUNT(UNIQUE(FILTER($B$2:$B$10,$C$2:$C$10=H2,"")))
Dynamic array formulas.


Your profile says you have 365, so FILTER should be available.
 
Last edited:
Upvote 0
Can you post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.
 
Upvote 0
Possibly:

Book1
HI
1IDUnique Route Count
288492
355963
444871
Sheet1
Cell Formulas
RangeFormula
H2:H4H2=UNIQUE(C2:C10)
I2:I4I2=COUNT(UNIQUE(FILTER($B$2:$B$10,$C$2:$C$10=H2,"")))
Dynamic array formulas.


Your profile says you have 365, so FILTER should be available.

Unfortunately it seems like i do not have FILTER available only FILTERXML. This version of 365 might not be fully updated?

Can you post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.

I am familiar with XL2BB however I am working currently from a work terminal and I am unable to use that tool with excel. :(
 
Upvote 0
Ok how about
Excel Formula:
=SUM(--(FREQUENCY(IF($C$2:$C$10=H2,$B$2:$B$10),$B$2:$B$10)>0))
This is an array formula & needs to be confirmed with Ctrl Shift Enter.
 
Upvote 0
Solution
Ok how about
Excel Formula:
=SUM(--(FREQUENCY(IF($C$2:$C$10=H2,$B$2:$B$10),$B$2:$B$10)>0))
This is an array formula & needs to be confirmed with Ctrl Shift Enter.
That works fantastic. will the formula update if i copy over the table in the C & B columns with new data (but same format)?

Also why does this need to be confirmed?
 
Upvote 0
As long as the data is numerical it should be ok.
Not all functions can automatically handle arrays, so they need to be array entered.
 
Upvote 0
As long as the data is numerical it should be ok.
Not all functions can automatically handle arrays, so they need to be array entered.
Thank you, you have saved me again.

I attempted an Array formula before this but it blew up the spreadsheet. this one seems to run fine!
 
Upvote 0

Forum statistics

Threads
1,214,588
Messages
6,120,409
Members
448,959
Latest member
camelliaCase

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