![]() |
How can I use the * wildcard in an array formula
Hi, I am trying to do a sumif in an array formula with 2 conditions.
In the second condition I am using the * wildcard to get cells that contain the characters Buy. The formula below entered as an array formula returns 0. I have confirmed that the array formula is treating the * literally, as a character rather than a wildcard. Is there a way around this? =SUM(IF((G$16:G$1000="Share Trade")*(H$16:H$1000="*Buy*"),I$16:I$1000)) Regards, Bruce |
How can I use the * wildcard in an array formula
Try the below
=SUMPRODUCT((G$16:G$1000="Share Trade")* (ISNUMBER(SEARCH("Buy",H$16:H$1000))),I$16:I$1000) If this post helps click Yes --------------- Jacob Skaria "Bruce" wrote: Hi, I am trying to do a sumif in an array formula with 2 conditions. In the second condition I am using the * wildcard to get cells that contain the characters Buy. The formula below entered as an array formula returns 0. I have confirmed that the array formula is treating the * literally, as a character rather than a wildcard. Is there a way around this? =SUM(IF((G$16:G$1000="Share Trade")*(H$16:H$1000="*Buy*"),I$16:I$1000)) Regards, Bruce |
How can I use the * wildcard in an array formula
Hi,
You may use this formula. C17 contains Share Trade and D17 contains buy =SUMPRODUCT(($G$16:$G$1000=C17)*(ISNUMBER(SEARCH(D 17,$H$16:$H$1000,1)))*($I$16:$I$1000)) Hope this helps. -- Regards, Ashish Mathur Microsoft Excel MVP www.ashishmathur.com "Bruce" wrote in message ... Hi, I am trying to do a sumif in an array formula with 2 conditions. In the second condition I am using the * wildcard to get cells that contain the characters Buy. The formula below entered as an array formula returns 0. I have confirmed that the array formula is treating the * literally, as a character rather than a wildcard. Is there a way around this? =SUM(IF((G$16:G$1000="Share Trade")*(H$16:H$1000="*Buy*"),I$16:I$1000)) Regards, Bruce |
How can I use the * wildcard in an array formula
Cool - thanks guys
Bruce "Ashish Mathur" wrote: Hi, You may use this formula. C17 contains Share Trade and D17 contains buy =SUMPRODUCT(($G$16:$G$1000=C17)*(ISNUMBER(SEARCH(D 17,$H$16:$H$1000,1)))*($I$16:$I$1000)) Hope this helps. -- Regards, Ashish Mathur Microsoft Excel MVP www.ashishmathur.com "Bruce" wrote in message ... Hi, I am trying to do a sumif in an array formula with 2 conditions. In the second condition I am using the * wildcard to get cells that contain the characters Buy. The formula below entered as an array formula returns 0. I have confirmed that the array formula is treating the * literally, as a character rather than a wildcard. Is there a way around this? =SUM(IF((G$16:G$1000="Share Trade")*(H$16:H$1000="*Buy*"),I$16:I$1000)) Regards, Bruce |
How can I use the * wildcard in an array formula
You are welcome.
-- Regards, Ashish Mathur Microsoft Excel MVP www.ashishmathur.com "Bruce" wrote in message ... Cool - thanks guys Bruce "Ashish Mathur" wrote: Hi, You may use this formula. C17 contains Share Trade and D17 contains buy =SUMPRODUCT(($G$16:$G$1000=C17)*(ISNUMBER(SEARCH(D 17,$H$16:$H$1000,1)))*($I$16:$I$1000)) Hope this helps. -- Regards, Ashish Mathur Microsoft Excel MVP www.ashishmathur.com "Bruce" wrote in message ... Hi, I am trying to do a sumif in an array formula with 2 conditions. In the second condition I am using the * wildcard to get cells that contain the characters Buy. The formula below entered as an array formula returns 0. I have confirmed that the array formula is treating the * literally, as a character rather than a wildcard. Is there a way around this? =SUM(IF((G$16:G$1000="Share Trade")*(H$16:H$1000="*Buy*"),I$16:I$1000)) Regards, Bruce |
All times are GMT +1. The time now is 02:03 AM. |
Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com