ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Sumproduct Wildcards (https://www.excelbanter.com/excel-worksheet-functions/232529-sumproduct-wildcards.html)

[email protected]

Sumproduct Wildcards
 
This works =Sumif($A3$:$A$43,"*Helm*",$F$3:$F$43)

Now I want to do that if TWO conditions are met, I typically use an
Array and Sumproduct, but can't get it to work. Thoughts?

It would the equivalent of doing this: =SUMPRODUCT(($F$3:$F$43)*($A
$3:$A$43="*Helm*")*($B$3:$B$43="*Port*")). But that doesn't work...

RagDyeR

Sumproduct Wildcards
 
Try this:

=SUMPRODUCT((ISNUMBER(SEARCH("Helm",$A$3:$A$43)))* (ISNUMBER(SEARCH("Port",$B$3:$B$43)))*$F$3:$F$43)

--

HTH,

RD
================================================== ===
Please keep all correspondence within the Group, so all may benefit!
================================================== ===

" wrote in message
...
This works =Sumif($A3$:$A$43,"*Helm*",$F$3:$F$43)

Now I want to do that if TWO conditions are met, I typically use an
Array and Sumproduct, but can't get it to work. Thoughts?

It would the equivalent of doing this: =SUMPRODUCT(($F$3:$F$43)*($A
$3:$A$43="*Helm*")*($B$3:$B$43="*Port*")). But that doesn't work...



Glenn

Sumproduct Wildcards
 
wrote:
This works =Sumif($A3$:$A$43,"*Helm*",$F$3:$F$43)

Now I want to do that if TWO conditions are met, I typically use an
Array and Sumproduct, but can't get it to work. Thoughts?

It would the equivalent of doing this: =SUMPRODUCT(($F$3:$F$43)*($A
$3:$A$43="*Helm*")*($B$3:$B$43="*Port*")). But that doesn't work...




=SUMPRODUCT(($F$3:$F$43)*
(ISNUMBER(FIND("Helm",$A$3:$A$43)))*
(ISNUMBER(FIND("Port",$B$3:$B$43))))

Luke M

Sumproduct Wildcards
 
You could try using this function, since the SEARCH function supports
wildcards.

=SUMPRODUCT(($F$3:$F$43)*(ISNUMBER(SEARCH("*Helm*" ,$A$3:$A$43)))*ISNUMBER(SEARCH("*Port*",$B$3:$B$43 )))

Note that SEARCH is non-case sensitive. If you want it to be, replace the
SEARCH's with FIND's.
--
Best Regards,

Luke M
*Remember to click "yes" if this post helped you!*


" wrote:

This works =Sumif($A3$:$A$43,"*Helm*",$F$3:$F$43)

Now I want to do that if TWO conditions are met, I typically use an
Array and Sumproduct, but can't get it to work. Thoughts?

It would the equivalent of doing this: =SUMPRODUCT(($F$3:$F$43)*($A
$3:$A$43="*Helm*")*($B$3:$B$43="*Port*")). But that doesn't work...


Glenn

Sumproduct Wildcards
 
Luke M wrote:
You could try using this function, since the SEARCH function supports
wildcards.

=SUMPRODUCT(($F$3:$F$43)*(ISNUMBER(SEARCH("*Helm*" ,$A$3:$A$43)))*ISNUMBER(SEARCH("*Port*",$B$3:$B$43 )))

Note that SEARCH is non-case sensitive. If you want it to be, replace the
SEARCH's with FIND's.



What is the difference between

=ISNUMBER(SEARCH("Helm",$A$3:$A$43))

and

=ISNUMBER(SEARCH("*Helm*",$A$3:$A$43))

Luke M

Sumproduct Wildcards
 
In this instance, none really. I was just copying OP's text. However, if you
wanted to check if a cell contained two or more words, it is nice to know you
can use wildcards.

E.g.
=SEARCH("bob*tom",A1)
would check look for the word bob followed sometime by the word tom. (also
supports the '?' character for single character wildcard.
--
Best Regards,

Luke M
*Remember to click "yes" if this post helped you!*


"Glenn" wrote:

Luke M wrote:
You could try using this function, since the SEARCH function supports
wildcards.

=SUMPRODUCT(($F$3:$F$43)*(ISNUMBER(SEARCH("*Helm*" ,$A$3:$A$43)))*ISNUMBER(SEARCH("*Port*",$B$3:$B$43 )))

Note that SEARCH is non-case sensitive. If you want it to be, replace the
SEARCH's with FIND's.



What is the difference between

=ISNUMBER(SEARCH("Helm",$A$3:$A$43))

and

=ISNUMBER(SEARCH("*Helm*",$A$3:$A$43))



All times are GMT +1. The time now is 06:52 AM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com