Sumproduct query (condition over two worksheets)

squire82

New Member
Joined
Jan 17, 2011
Messages
6
I'm using Excel 2003

I have two worksheets, one named retail, the other corp. For this example both have the same information below.

A B C
<TABLE style="WIDTH: 151pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=201 border=0 x:str><COLGROUP><COL style="WIDTH: 55pt; mso-width-source: userset; mso-width-alt: 2588" width=73><COL style="WIDTH: 48pt" span=2 width=64><TBODY><TR style="HEIGHT: 13.2pt" height=18><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; WIDTH: 55pt; BORDER-BOTTOM: #e0e0e0; HEIGHT: 13.2pt; BACKGROUND-COLOR: transparent" width=73 height=18>Date</TD><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; WIDTH: 48pt; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent" width=64>Product</TD><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; WIDTH: 48pt; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent" width=64>Sales</TD></TR><TR style="HEIGHT: 13.2pt" height=18><TD class=xl24 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; HEIGHT: 13.2pt; BACKGROUND-COLOR: transparent" height=18 x:num="40553">10/01/2011</TD><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent">Pension</TD><TD class=xl25 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent" x:num>1000.00</TD></TR><TR style="HEIGHT: 13.2pt" height=18><TD class=xl24 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; HEIGHT: 13.2pt; BACKGROUND-COLOR: transparent" height=18 x:num="40558">15/01/2011</TD><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent">Pension</TD><TD class=xl25 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent" x:num>750.00</TD></TR><TR style="HEIGHT: 13.2pt" height=18><TD class=xl24 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; HEIGHT: 13.2pt; BACKGROUND-COLOR: transparent" height=18 x:num="40571">28/01/2011</TD><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent">Pension</TD><TD class=xl25 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent" x:num>250.00</TD></TR><TR style="HEIGHT: 13.2pt" height=18><TD class=xl24 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; HEIGHT: 13.2pt; BACKGROUND-COLOR: transparent" height=18 x:num="40575">01/02/2011</TD><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent">Pension</TD><TD class=xl25 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent" x:num>500.00</TD></TR><TR style="HEIGHT: 13.2pt" height=18><TD class=xl24 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; HEIGHT: 13.2pt; BACKGROUND-COLOR: transparent" height=18 x:num="40602">28/02/2011</TD><TD style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent">Pension</TD><TD class=xl25 style="BORDER-RIGHT: #e0e0e0; BORDER-TOP: #e0e0e0; BORDER-LEFT: #e0e0e0; BORDER-BOTTOM: #e0e0e0; BACKGROUND-COLOR: transparent" x:num>500.00</TD></TR></TBODY></TABLE>

In worksheet three, I want to get the total sales for pensions across both retail and corp. I'm using the following formula:

=SUMPRODUCT((retail!$B$2:$B$100="pension")*(retail!$A$2:$A$100>="01/01/2011"+0)*(retail!$A$2:$A$100<="31/01/2011"+0),(retail!$C$2:$C$100)--(corp!$B$2:$B$100="pension")*(corp!$A$2:$A$100>="01/01/2011"+0)*(corp!$A$2:$A$100<="31/01/2011"+0),(corp!$C$2:$C$100))

Total sales for January should amount to 4000, but the figure I'm getting is way off.

Thanks in advance for your help.
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Seems like you have a run-on sentence. Try

=SUMPRODUCT((retail!$A$2:$A$100>=--"01/01/2011") * (retail!$A$2:$A$100<=--"31/01/2011") * (retail!$B$2:$B$100="pension"), retail!$C$2:$C$100)
+SUMPRODUCT((corp!$A$2:$A$100>=--"01/01/2011") * (corp!$A$2:$A$100<=--"31/01/2011") * (corp!$B$2:$B$100="pension"), corp!$C$2:$C$100)

or

=SUMIFS(retail!$C$2:$C$100, retail!$A$2:$A$100, ">=01/01/2011", retail!$A$2:$A$100, "<=31/01/2011", retail!$B$2:$B$100, "pension")
+SUMIFS(corp!$C$2:$C$100, corp!$A$2:$A$100, ">=01/01/2011", corp!$A$2:$A$100, "<=31/01/2011", corp!$B$2:$B$100, "pension")
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,521
Messages
6,179,282
Members
452,902
Latest member
Knuddeluff

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