Sumproduct help

MikeGazzy

New Member
Joined
Jul 8, 2020
Messages
3
Office Version
  1. 2013
Platform
  1. Windows
I have a report that references an external workbook and utilizes sumifs statements so some of my users are getting #VALUE errors when the source workbooks aren't open. I would like to utilize sumproduct instead since I have read that it will fix this issue but I don't have any experience with it and am running into some issues trying to convert my formula. Here is the original sumifs statement I would like to convert:
=SUM(SUMIFS([Source]Sheet!'!$I$1:$I$65536,[Source]Sheet!'!$C$1:$C$65536,101,[Source]Sheet!'!$J$1:$J$65536,{"Breakage","Cycle Count","Manager Cycle Count"}, [Source]Sheet!'! $L$1:$L$65536,$A3))
I think my main issue is converting the array formula section of my original statement but it could be something else I am missing? Thanks in advance for any help.

Thanks,

Mike
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
May be like this
SUMPRODUCT([Source]Sheet!'!$I$1:$I$65536,[Source]Sheet!'!$C$1:$C$65536=101,[Source]Sheet!'!$J$1:$J$65536={"Breakage","Cycle Count","Manager Cycle Count"},[Source]Sheet!'! $L$1:$L$65536=$A3)
 
Upvote 0
Nope, that is basically more or less what I have been trying, I also tried expanding the array formula out into 3 different statements with a + in between them but that didn't work.
 
Upvote 0
Sorry I missed

[Source]Sheet!'!$J$1:$J$65536={"Breakage","Cycle Count","Manager Cycle Count"} will give an error,

use this instead
ISNUMBER(MATCH(C3:C51,{"chicken";"Egg"},0)) and try
 
Upvote 0
SUMPRODUCT([Source]Sheet!'!$I$1:$I$65536,--([Source]Sheet!'!$C$1:$C$65536=101),--(ISNUMBER(MATCH([Source]Sheet!'!$J$1:$J$65536,"}, {"Breakage";"Cycle Count";"Manager Cycle Count"} 0)) ,--([Source]Sheet!'! $L$1:$L$65536=$A3))
 
Upvote 0
Sorry I missed

[Source]Sheet!'!$J$1:$J$65536={"Breakage","Cycle Count","Manager Cycle Count"} will give an error,

use this instead
ISNUMBER(MATCH(C3:C51,{"chicken";"Egg"},0)) and try
Ignore This
 
Upvote 0
I prepared a small example and the following works.
I show two views of the formula; one with the file open and one with the file closed.
K1:K3 has the 3 criteria like Breakage

=SUMPRODUCT(--([Source.xlsm]Sheet!$I$1:$I$20),--([Source.xlsm]Sheet!$C$1:$C$20=101),--(ISNUMBER(MATCH([Source.xlsm]Sheet!$J$1:$J$20,K1:K3,0))),--([Source.xlsm]Sheet!$L$1:$L$20=$A3))

with file closed
=SUMPRODUCT(--('D:\Excel14\[Source.xlsm]Sheet'!$I$1:$I$20),--('D:\Excel14\[Source.xlsm]Sheet'!$C$1:$C$20=101),--(ISNUMBER(MATCH('D:\Excel14\[Source.xlsm]Sheet'!$J$1:$J$20,K1:K3,0))),--('D:\Excel14\[Source.xlsm]Sheet'!$L$1:$L$20=$A3))
 
Upvote 0
I prepared a small example and the following works.
I show two views of the formula; one with the file open and one with the file closed.
K1:K3 has the 3 criteria like Breakage

=SUMPRODUCT(--([Source.xlsm]Sheet!$I$1:$I$20),--([Source.xlsm]Sheet!$C$1:$C$20=101),--(ISNUMBER(MATCH([Source.xlsm]Sheet!$J$1:$J$20,K1:K3,0))),--([Source.xlsm]Sheet!$L$1:$L$20=$A3))

with file closed
=SUMPRODUCT(--('D:\Excel14\[Source.xlsm]Sheet'!$I$1:$I$20),--('D:\Excel14\[Source.xlsm]Sheet'!$C$1:$C$20=101),--(ISNUMBER(MATCH('D:\Excel14\[Source.xlsm]Sheet'!$J$1:$J$20,K1:K3,0))),--('D:\Excel14\[Source.xlsm]Sheet'!$L$1:$L$20=$A3))
Perfect, that got it to work. Thanks so much.
 
Upvote 0

Forum statistics

Threads
1,213,490
Messages
6,113,957
Members
448,535
Latest member
alrossman

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