Countif unique text value but with 2 conditions

Bering

Board Regular
Joined
Aug 22, 2018
Messages
176
Office Version
  1. 2016
Platform
  1. Windows
Hi All,

I hope someone can help me with this problem:

I want to count the unique text occurrences in column I but only if the value in column D is "Futures".

So far I managed to resolve part of the problem by "hard-coding" the range in the formula below:

SUMPRODUCT(--(FREQUENCY(MATCH('Data'!I29:I38,'Data'!I29:I38,0),ROW('Data'!I29:I38)-ROW('Data'!I29)+1)>0))

However, this should be changed so that it counts the unique values in Column I:I only if the value in column D is "Futures".

I have been wasting a disproportionate amount of time with this so I would really appreciate any ideas/help.

Thanks!
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Try...

Code:
=SUMPRODUCT(--(FREQUENCY(IF(Data!D29:D38="Futures",MATCH(Data!I29:I38,Data!I29:I38,0)),ROW(Data!I29:I38)-ROW(Data!I29)+1)>0))

or

Code:
=SUM(IF(FREQUENCY(IF(Data!D29:D38="Futures",MATCH(Data!I29:I38,Data!I29:I38,0)),ROW(Data!I29:I38)-ROW(Data!I29)+1)>0,1))

Note that both formulas need to be confirmed with CONTROL+SHIFT+ENTER, not just ENTER.

Hope this helps!
 
Upvote 0
Solution
Thank you very much for this.

However, I still have an issue with this formula: what I would like to achieve is referring to the range as I:I (the entire column), rather than having to fix the range as in the current formula. The actual range should be determined by the IF condition in column D.

I tried to change the formula as shown below but it does not work....

Any ideas? Many thanks.



Code:
=[COLOR=#333333]SUMPRODUCT(--(FREQUENCY(IF(Data!D:D="Futures",MATCH(Data!I:I,Data!I:I,0)),ROW(Data!I:I)-ROW(Data!I1)+1)>0))[/COLOR]


Try...

Code:
=SUMPRODUCT(--(FREQUENCY(IF(Data!D29:D38="Futures",MATCH(Data!I29:I38,Data!I29:I38,0)),ROW(Data!I29:I38)-ROW(Data!I29)+1)>0))

or

Code:
=SUM(IF(FREQUENCY(IF(Data!D29:D38="Futures",MATCH(Data!I29:I38,Data!I29:I38,0)),ROW(Data!I29:I38)-ROW(Data!I29)+1)>0,1))

Note that both formulas need to be confirmed with CONTROL+SHIFT+ENTER, not just ENTER.

Hope this helps!
 
Last edited:
Upvote 0
Using whole column references is extremely inefficient. Instead, convert your data into a Table (Ribbon >> Insert >> Table) or define a dynamic named range. In either case, the range will automatically adjust as data is added/removed.
 
Upvote 0

Forum statistics

Threads
1,213,552
Messages
6,114,278
Members
448,560
Latest member
Torchwood72

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