Formula to return unique values based on 4 criteria

thomasuponor

New Member
Joined
Sep 13, 2018
Messages
44
Office Version
  1. 2016
Platform
  1. Windows
Hello everybody,

I want to count unique value with following formula, which usually works, but does not for this task. The extra add on is Data'!$AA:$AA;"*Dahl*" (I believe this is the reason it's not working)


Code:
=SUM(--(FREQUENCY(IF(('Visit Data'!$AD:$AD="Distributor")*(ISNUMBER(SEARCH('Visit Data'!$AG:$AG;"Visit")))*(ISNUMBER(SEARCH('Visit Data'!$V:$V;"Kim")))*(ISNUMBER(SEARCH('Visit Data'!$AA:$AA;"*Dahl*")));MATCH('Visit Data'!$AA:$AA;'Visit Data'!$AA:$AA;0));ROW('Visit Data'!$AA:$AA)-ROW('Visit Data'!$AA$3)+1)>0))

Anyone able to provide help here?
Thx
 

Excel Facts

Will the fill handle fill 1, 2, 3?
Yes! Type 1 in a cell. Hold down Ctrl while you drag the fill handle.
Are you sure this approach has usually worked? The SEARCH functions appear to have the arguments in reverse order. If you want a count where all of those conditions are met in the same row, then try:
=COUNTIFS('Visit Data'!$AD:$AD,"*Distributor*",'Visit Data'!$AG:$AG,"*Visit*",'Visit Data'!$V:$V,"*Kim*",'Visit Data'!$AA:$AA,"*Dahl*")
 
Upvote 0
x-posted at EF.com but, if you have access to O365 functions you could use UNIQUE + FILTER as an alternative, i.e.:

=COUNTA(UNIQUE(FILTER('Visit Data'!$AA:$AA;ISNUMBER(('Visit Data'!$AD:$AD="Distributor")*SEARCH("Visit";'Visit Data'!$AG:$AG)*SEARCH("Kim";'Visit Data'!$V:$V)*SEARCH("Dahl";'Visit Data'!$AA:$AA))))
 
Upvote 0
Are you sure this approach has usually worked? The SEARCH functions appear to have the arguments in reverse order. If you want a count where all of those conditions are met in the same row, then try:
=COUNTIFS('Visit Data'!$AD:$AD,"*Distributor*",'Visit Data'!$AG:$AG,"*Visit*",'Visit Data'!$V:$V,"*Kim*",'Visit Data'!$AA:$AA,"*Dahl*")

Yes, have been using this formula for a while and it's working. Using the =countifs does not return the unique values.
 
Upvote 0
x-posted at EF.com but, if you have access to O365 functions you could use UNIQUE + FILTER as an alternative, i.e.:

=COUNTA(UNIQUE(FILTER('Visit Data'!$AA:$AA;ISNUMBER(('Visit Data'!$AD:$AD="Distributor")*SEARCH("Visit";'Visit Data'!$AG:$AG)*SEARCH("Kim";'Visit Data'!$V:$V)*SEARCH("Dahl";'Visit Data'!$AA:$AA))))
Unfortunately, I am nut using 0365.
 
Upvote 0
=SUM(--(FREQUENCY(IF(ISNUMBER(('Visit Data'!$AD:$AD="Distributor")*SEARCH("Visit";'Visit Data'!$AG:$AG)*SEARCH("Kim";'Visit Data'!$V:$V)*SEARCH("Dahl";'Visit Data'!$AA:$AA));MATCH('Visit Data'!$AA:$AA;'Visit Data'!$AA:$AA;0));ROW('Visit Data'!$AA:$AA))>0))
confirmed with CTRL + SHIFT + ENTER

however, you shouldn't use entire column references with Arrays -- use either (non-volatile) Dynamic Named Ranges, or Tables.
 
Upvote 0
What result do you get with the formula I posted? Here is an example where the count is shown in U1 where each text string is found on the same row in the specified columns. Is that what you want to count?
Book1
TUVWXYZAAABACADAEAFAG
1Count -->2
2acmeVisit
3
4Jung KimAbe Dahlberga Distributor hereVisit
5Andy KimObdahl Lua distributor thereA nice visit here
6JacobJohnnot a distA nice visit there
Visit Data
Cell Formulas
RangeFormula
U1U1=COUNTIFS('Visit Data'!$AD:$AD,"*Distributor*",'Visit Data'!$AG:$AG,"*Visit*",'Visit Data'!$V:$V,"*Kim*",'Visit Data'!$AA:$AA,"*Dahl*")

Did you convert the commas to semicolons?...it looks like you have that preference set?
 
Upvote 0
correction:

=SUM(--(FREQUENCY(IF(ISNUMBER(SEARCH("Visit";'Visit Data'!$AG:$AG)*SEARCH("Kim";'Visit Data'!$V:$V)*SEARCH("Dahl";'Visit Data'!$AA:$AA)/('Visit Data'!$AD:$AD="Distributor"));MATCH('Visit Data'!$AA:$AA;'Visit Data'!$AA:$AA;0));ROW('Visit Data'!$AA:$AA))>0))
confirmed with CTRL + SHIFT + ENTER
 
Upvote 0
It looks like what @DonkeyOte posted works fine. I still don't understand why the non-array formula I suggested won't work, unless the commas were left unchanged. It also appears that you want only instances where column AD contains "Distributor" rather than that string found anywhere, so a revised version would be:
=COUNTIFS('Visit Data'!$AD:$AD;"Distributor";'Visit Data'!$AG:$AG;"*Visit*";'Visit Data'!$V:$V;"*Kim*";'Visit Data'!$AA:$AA;"*Dahl*")
 
Upvote 0
Hi @KRice, the issue with the COUNTIFS would be duplicates of any "Dahl" variant in AA:AA.
(you could create a SUMPRODUCT/COUNTIFS based alternative to the FREQUENCY array -- and tbh, as I coded it there won't be much difference in performance... if you separate the various Boolean tests into discrete / pre-emptive IFs the Array will likely perform better, I would say.
 
Upvote 0

Forum statistics

Threads
1,224,818
Messages
6,181,152
Members
453,021
Latest member
Justyna P

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