SUMPRODUCT with fuzzy wildcard search but also with NOT statement

Joined
Jul 7, 2021
Messages
2
Office Version
  1. 2019
Platform
  1. Windows
Hello all

I have a working formula that will provide me a count on the basis of explicitly stated search criteria, a fuzzy 'wildcard' based search. It is the following:

=SUMPRODUCT(($A$4:$A$2851=$M8)*(--(ISNUMBER(SEARCH(N$2,$C$4:$I$2851))*(--(ISNUMBER(SEARCH($L8,$C$4:$I$2851)))))))

However, as part of this count I would like to exclude the count from any cells that contain for instance the word 'boost'. To achieve this, in cell J9 I have written *boost* and changed the formula to the following:

=SUMPRODUCT(($A$4:$A$2851=$M9)*(--(ISNUMBER(SEARCH(N$2,$C$4:$I$2851))*(--(ISNUMBER(SEARCH($L9,$C$4:$I$2851)*(--(NOT(ISNUMBER(SEARCH($J9,$C$4:$I$2851)))))))))))`

This however has not excluded any matches that also include the term 'boost' in the cell. It simply produces exactly the same count as before.

Could any help possibly be given with this please?

Much appreciated
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
You have misplaced brackets plus you dont need the * in the cell. Try this:

=SUMPRODUCT(($A$4:$A$2851=$M9)*(ISNUMBER(SEARCH(N$2,$C$4:$I$2851)))*(ISNUMBER(SEARCH($L9,$C$4:$I$2851)))*(NOT(ISNUMBER(SEARCH($J9,$C$4:$I$2851)))))
 
Upvote 0
Thank you very much Steve ! Appears to work perfectly. I guess I don't need the -- prefix to the isnumber then. Also good to know I don't need the * when searching the cell - I guess this is only perhaps needed with SUMIFS / Index Match etc.

Hope I can be a credit to the world with something like what you do one day !
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,561
Members
449,089
Latest member
Motoracer88

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