Home |
Search |
Today's Posts |
#1
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Hi Team,
was wondering if you could help me.... I am using the below formula =SUMPRODUCT(--(Data!$H$1:$H$5000="||||||||MIC|||||||||||"),--(Data!$G$1:$G$5000="Ashley Tobin")) the problem is, as you can probably see, the data is not very clean.. sometimes the data looks like this ||||||||MIC||||||||||| other times it will be |||||||Investments & returns|MIC||||||||||| using count if I can use wildcards and it works nicely. =COUNTIF(Data!$H:$H,"*MIC*") but they don't ( or I can't seem to get them to ) work when using sumproduct... any suggestions?? thanks Mark... |
#2
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
"Madduck" wrote...
.... =SUMPRODUCT(--(Data!$H$1:$H$5000="||||||||MIC|||||||||||"), --(Data!$G$1:$G$5000="Ashley Tobin")) the problem is, as you can probably see, the data is not very clean.. sometimes the data looks like this ||||||||MIC||||||||||| other times it will be |||||||Investments & returns|MIC||||||||||| .... =SUMPRODUCT(--ISNUMBER(FIND("|MIC|",Data!$H$1:$H$5000)), --(Data!$G$1:$G$5000="Ashley Tobin"))) |
#3
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
"Harlan Grove" wrote in message
... "Madduck" wrote... ... =SUMPRODUCT(--(Data!$H$1:$H$5000="||||||||MIC|||||||||||"), --(Data!$G$1:$G$5000="Ashley Tobin")) the problem is, as you can probably see, the data is not very clean.. sometimes the data looks like this ||||||||MIC||||||||||| other times it will be |||||||Investments & returns|MIC||||||||||| ... =SUMPRODUCT(--ISNUMBER(FIND("|MIC|",Data!$H$1:$H$5000)), --(Data!$G$1:$G$5000="Ashley Tobin"))) Geez! Here I thought those "vertical bars" were some kind of strange formatting escape chararcter that I've never seen before but they're just your standard pipe characters! -- Biff Microsoft Excel MVP |
#4
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Thank you very much, that worked a treat... I expanded a little for the
formula to read : =SUMPRODUCT(--ISNUMBER(FIND("MIC",Data!$H$1:$H$5000)), --ISNUMBER(FIND("ley Tob",Data!$G$1:$G$5000))) now it really doesn't matter how clean the data is.. Thanks again Harlan. Mark. "Harlan Grove" wrote: "Madduck" wrote... .... =SUMPRODUCT(--(Data!$H$1:$H$5000="||||||||MIC|||||||||||"), --(Data!$G$1:$G$5000="Ashley Tobin")) the problem is, as you can probably see, the data is not very clean.. sometimes the data looks like this ||||||||MIC||||||||||| other times it will be |||||||Investments & returns|MIC||||||||||| .... =SUMPRODUCT(--ISNUMBER(FIND("|MIC|",Data!$H$1:$H$5000)), --(Data!$G$1:$G$5000="Ashley Tobin"))) |
#5
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
"Madduck" wrote...
.... =SUMPRODUCT(--ISNUMBER(FIND("MIC",Data!$H$1:$H$5000)), --ISNUMBER(FIND("ley Tob",Data!$G$1:$G$5000))) .... I didn't put the vertical bars in my formula by accident. If 'MIC' could appear as a substring in some other bar-delimited field in col H, then you could get false hits searching for "MIC" rather then searching for the bar-delimited field "|MIC|". For example, |||||||SYSTEMIC FAILUE|||||||| would be treated as a match in your formula. |
#6
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Thanks Harlan,
yep I did realise that. Thanks again. "Harlan Grove" wrote: "Madduck" wrote... .... =SUMPRODUCT(--ISNUMBER(FIND("MIC",Data!$H$1:$H$5000)), --ISNUMBER(FIND("ley Tob",Data!$G$1:$G$5000))) .... I didn't put the vertical bars in my formula by accident. If 'MIC' could appear as a substring in some other bar-delimited field in col H, then you could get false hits searching for "MIC" rather then searching for the bar-delimited field "|MIC|". For example, |||||||SYSTEMIC FAILUE|||||||| would be treated as a match in your formula. |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Sumproduct with wildcards | Excel Worksheet Functions | |||
sumproduct won't accept wildcards | Excel Worksheet Functions | |||
Sumproduct and wildcards | Excel Worksheet Functions | |||
Can wildcards be used in SUMPRODUCT conditions | Excel Worksheet Functions | |||
Wildcards with SumProduct | Excel Worksheet Functions |