ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   Sumproduct syntax - more complex (https://www.excelbanter.com/excel-discussion-misc-queries/118208-sumproduct-syntax-more-complex.html)

Mitchell

Sumproduct syntax - more complex
 
I have a more complex sumproduct syntax problem
=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),--(OR((Tasks!CJ1:CJ900="New"),(Tasks!CJ1:CJ900="In
Progress"),(Tasks!CJ1:CJ900="In Progress - New"))),Tasks!CG1:CG900)

The equation worked fine, then I added the OR statement. The values for the
OR statement are all false, so the OR statement should be false. This means
the sumproduct should resolve to a 0, instead I am resolving to a #VALUE.
Where have I made an error?

Bob Phillips

Sumproduct syntax - more complex
 
=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),
--((Tasks!CJ1:CJ900="New")+(Tasks!CJ1:CJ900="In
Progress")+(Tasks!CJ1:CJ900="In Progress - New")),Tasks!CG1:CG900)

or

=SUMPRODUCT((Tasks!CI1:CI900="dduplessis")*(Tasks! N1:N900<"CUT")*
((Tasks!CJ1:CJ900={"New","In Progress","In Progress -
New"}))*Tasks!CG1:CG900)

--
HTH

Bob Phillips

(replace somewhere in email address with gmail if mailing direct)

"Mitchell" wrote in message
...
I have a more complex sumproduct syntax problem

=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),--(OR(
(Tasks!CJ1:CJ900="New"),(Tasks!CJ1:CJ900="In
Progress"),(Tasks!CJ1:CJ900="In Progress - New"))),Tasks!CG1:CG900)

The equation worked fine, then I added the OR statement. The values for

the
OR statement are all false, so the OR statement should be false. This

means
the sumproduct should resolve to a 0, instead I am resolving to a #VALUE.
Where have I made an error?




Domenic

Sumproduct syntax - more complex
 
Try...

=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),(Ta
sks!CJ1:CJ900="New")+(Tasks!CJ1:CJ900="In
Progress")+(Tasks!CJ1:CJ900="In Progress - New"),Tasks!CG1:CG900)

Hope this helps!

In article ,
Mitchell wrote:

I have a more complex sumproduct syntax problem
=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),--(OR((T
asks!CJ1:CJ900="New"),(Tasks!CJ1:CJ900="In
Progress"),(Tasks!CJ1:CJ900="In Progress - New"))),Tasks!CG1:CG900)

The equation worked fine, then I added the OR statement. The values for the
OR statement are all false, so the OR statement should be false. This means
the sumproduct should resolve to a 0, instead I am resolving to a #VALUE.
Where have I made an error?


Domenic

Sumproduct syntax - more complex
 
Actually, I believe the following is more efficient...

=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),--I
SNUMBER(MATCH(Tasks!CJ1:CJ900,{"New","In Progress","In Progress -
New"},0)),Tasks!CG1:CG900)

or

=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),--I
SNUMBER(MATCH(Tasks!CJ1:CJ900,A2:A4,0)),Tasks!CG1: CG900)

....where A2:A4 contains New, In Progress, and In Progress - New.

Hope this helps!

In article ,
Domenic wrote:

Try...

=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),(Ta
sks!CJ1:CJ900="New")+(Tasks!CJ1:CJ900="In
Progress")+(Tasks!CJ1:CJ900="In Progress - New"),Tasks!CG1:CG900)

Hope this helps!

In article ,
Mitchell wrote:

I have a more complex sumproduct syntax problem
=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),--(OR(
(T
asks!CJ1:CJ900="New"),(Tasks!CJ1:CJ900="In
Progress"),(Tasks!CJ1:CJ900="In Progress - New"))),Tasks!CG1:CG900)

The equation worked fine, then I added the OR statement. The values for the
OR statement are all false, so the OR statement should be false. This means
the sumproduct should resolve to a 0, instead I am resolving to a #VALUE.
Where have I made an error?


Mitchell

Sumproduct syntax - more complex
 
Thanks, it worked perfectly

"Bob Phillips" wrote:

=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),
--((Tasks!CJ1:CJ900="New")+(Tasks!CJ1:CJ900="In
Progress")+(Tasks!CJ1:CJ900="In Progress - New")),Tasks!CG1:CG900)

or

=SUMPRODUCT((Tasks!CI1:CI900="dduplessis")*(Tasks! N1:N900<"CUT")*
((Tasks!CJ1:CJ900={"New","In Progress","In Progress -
New"}))*Tasks!CG1:CG900)

--
HTH

Bob Phillips

(replace somewhere in email address with gmail if mailing direct)

"Mitchell" wrote in message
...
I have a more complex sumproduct syntax problem

=SUMPRODUCT(--(Tasks!CI1:CI900="dduplessis"),--(Tasks!N1:N900<"CUT"),--(OR(
(Tasks!CJ1:CJ900="New"),(Tasks!CJ1:CJ900="In
Progress"),(Tasks!CJ1:CJ900="In Progress - New"))),Tasks!CG1:CG900)

The equation worked fine, then I added the OR statement. The values for

the
OR statement are all false, so the OR statement should be false. This

means
the sumproduct should resolve to a 0, instead I am resolving to a #VALUE.
Where have I made an error?






All times are GMT +1. The time now is 01:27 AM.

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