Need to count unique values in a sorted list

mrwilliams

New Member
Joined
Mar 1, 2007
Messages
8
I have an excal table with about 85,000 lines. I need to match on one column and once the match is true, I need to count all the unique values in a second column without counting duplicates. Column "Prod Tab" is the column I need to match and column "SubID" are the values that I need unique counts on.

Example follows:

SubID Prod Tab
824510 9
601632 9
601632 9
601632 9
601632 9
601632 9
601632 9
828280 9
616411 9
616411 9
616411 9
616411 9
616411 9
830160 9
800676 9
800676 9
800676 9
800676 9
800676 9
800676 9

Prod Tab can be a value from 0 to 13. In this example I am matching on "9" in the column and those rows mathced I want to determine the number of unique values in the SubID column. It this example the end result would be "6".

I can do this with a piviot table, but was hoping to accomplish it with VBA and report the results of each such test to a spefice range.

Can some sheer me to a solution?

Mr G Williams
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Control+shift+enter, not just enter:
Code:
=SUM(IF(FREQUENCY(IF($A$2:$A$21<>"",IF($B$2:$B$21=E2,
   MATCH("~"&$A$2:$A$21,$A$2:$A$21&"",0)),
    ROW($A$2:$A$21)-ROW($A$2)+1),1))

You can remove the "~"& and &"" bits from this formula for the data you have do not seem
to house entries with special meaning chars like <, etc.
 
Upvote 0
here's a another alternative... again, entered as array (ctrl+shift+enter)

=SUM(IF(B1:B20=9,1/COUNTIF(A1:A20,A1:A20),FALSE))

replace 9 with corresponding value (or reference), & change the reference to suit your needs.
 
Last edited:
Upvote 0
Control+shift+enter, not just enter:
Code:
=SUM(IF(FREQUENCY(IF($A$2:$A$21<>"",IF($B$2:$B$21=E2,
   MATCH("~"&$A$2:$A$21,$A$2:$A$21&"",0)),
    ROW($A$2:$A$21)-ROW($A$2)+1),1))

You can remove the "~"& and &"" bits from this formula for the data you have do not seem
to house entries with special meaning chars like <, etc.

Oops... A paren is missing up there...

Code:
=SUM(IF(FREQUENCY(IF($A$2:$A$21<>"",IF($B$2:$B$21=E2,
   MATCH("~"&$A$2:$A$21,$A$2:$A$21&"",0))),
    ROW($A$2:$A$21)-ROW($A$2)+1),1))
 
Upvote 0
here's a another alternative... again, entered as array (ctrl+shift+enter)

=SUM(IF(B1:B20=9,1/COUNTIF(A1:A20,A1:A20),FALSE))

replace 9 with corresponding value (or reference), & change the reference to suit your needs.

Try to run this on the sample. Change one of the 9's to 8 or simply delete one such entry. BTW, even corrected, it's not as fast.
 
Last edited:
Upvote 0
This code worked like a charm on the sample of 20 rows:

=SUM(IF(B1:B20=9,1/COUNTIF(A1:A20,A1:A20),FALSE))

When I applied it to the 80,000 lines, well..... crashed excel.

Is there a way to program this as a function so I can do this as part of a VBA script?

Mr G
 
Upvote 0
This code worked like a charm on the sample of 20 rows:

=SUM(IF(B1:B20=9,1/COUNTIF(A1:A20,A1:A20),FALSE))

When I applied it to the 80,000 lines, well..... crashed excel.

Is there a way to program this as a function so I can do this as part of a VBA script?

Mr G

Did you try the other, corrected formula? That is:

=SUM(IF(FREQUENCY(IF($A$2:$A$21<>"",IF($B$2:$B$21=E2, MATCH($A$2:$A$21,$A$2:$A$21,0))), ROW($A$2:$A$21)-ROW($A$2)+1),1))

where E2 is set to 9?
 
Upvote 0
This is what the formula looks like revised using the proper array dim's.

=SUM(IF(FREQUENCY(IF($A$2:$A$80779<>"",IF($B$2:$B$80779=9, MATCH($A$2:$A$80779,$A$2:$A$80779,0))), ROW($A$2:$A$80779)-ROW($A$2)+1),1))

Results: #VALUE!

I am puzzled....

Mr G.
 
Upvote 0
This is what the formula looks like revised using the proper array dim's.

=SUM(IF(FREQUENCY(IF($A$2:$A$80779<>"",IF($B$2:$B$80779=9, MATCH($A$2:$A$80779,$A$2:$A$80779,0))), ROW($A$2:$A$80779)-ROW($A$2)+1),1))

Results: #VALUE!

I am puzzled....

Mr G.

You need to apply the key combination control, shift, and enter at the same time. If done properly, the formula will be encolsed between { and }.

The ranges you have are huge. I'm curious how the formula will behave!
 
Upvote 0
BTW MrW,

just curious - why do you need to apply either my or Aladin's formula to the entire range of 80,000 rows?

as you said, you only have 13 numbers in the second column. cant you just do a one-time calculation (so have numbers from 1 to 13 in say, col, J1:J13), and next to it (K1:K13) the corresponding counts for those 13 using either formulas.

then for those 80,000 rows, do a simple vlookup based on that 13-line long column. will be MUCH faster, at least you wont be using an array formula for the entire sheet
 
Upvote 0

Forum statistics

Threads
1,214,611
Messages
6,120,513
Members
448,967
Latest member
screechyboy79

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