Question> Sumproduct multiple variables... count only certain results

collegeitdept

Board Regular
Joined
Nov 14, 2008
Messages
185
Hello I need a Sumproduct like formula that will return the count of how many weeks there are for Season 1 (or variable # for season) for a certain show & platform:





[TABLE="class: grid, width: 500, align: center"]
<tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[TD]E[/TD]
[TD]F[/TD]
[TD]G[/TD]
[TD]H[/TD]
[TD]I[/TD]
[TD]J[/TD]
[TD]K[/TD]
[TD]L[/TD]
[TD]M[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD][/TD]
[TD]Show1[/TD]
[TD]Show1[/TD]
[TD]Show1[/TD]
[TD]Show1[/TD]
[TD]Show2[/TD]
[TD]Show2[/TD]
[TD]Show2[/TD]
[TD]Show2[/TD]
[TD]Show3[/TD]
[TD]Show3[/TD]
[TD]Show3[/TD]
[TD]Show3[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]Date[/TD]
[TD]Platform1[/TD]
[TD]Platform2[/TD]
[TD]Platform3[/TD]
[TD]Season[/TD]
[TD]Platform1[/TD]
[TD]Platform2[/TD]
[TD]Platform3[/TD]
[TD]Season[/TD]
[TD]Platform1[/TD]
[TD]Platform2[/TD]
[TD]Platform3[/TD]
[TD]Season[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]9/15[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]368[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]139[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]6945[/TD]
[TD][/TD]
[TD]4312[/TD]
[TD]168[/TD]
[TD]765[/TD]
[TD]1[/TD]
[TD]864[/TD]
[TD]25357[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]20369[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]9/22[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]7118[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]19645[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]56355[/TD]
[TD][/TD]
[TD]8763[/TD]
[TD]854[/TD]
[TD]8254[/TD]
[TD]1[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]20369[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]978[/TD]
[TD]852[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]9/29[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]17899[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]648[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]45[/TD]
[TD]1[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]20369[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]4569[/TD]
[TD]853[/TD]
[TD]1[/TD]
[TD]78465[/TD]
[TD]8978[/TD]
[TD]453[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]10/6[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]20361[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]20369[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]9465[/TD]
[TD]1[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]648[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]139[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]65478[/TD]
[TD]1[/TD]
[TD]1476[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]139[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]20369[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]10/13[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]17726[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]272[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]4535[/TD]
[TD]1[/TD]
[TD]8654[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]20369[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]1235[/TD]
[TD]1[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]327[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]865[/TD]
[TD]7856[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]10/20[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]19650[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]177[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]4135[/TD]
[TD]1[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]19645[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]4632[/TD]
[TD]642[/TD]
[TD]1[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]19645[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]327[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]2220[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]10/27[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]12026[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]354[/TD]
[TD]5343[/TD]
[TD][/TD]
[TD]536[/TD]
[TD]4535[/TD]
[TD]21656[/TD]
[TD]1[/TD]
[TD]2435[/TD]
[TD]4547[/TD]
[TD]78[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]11/3[/TD]
[TD]45345[/TD]
[TD]455[/TD]
[TD]8936[/TD]
[TD][/TD]
[TD]548[/TD]
[TD]3213[/TD]
[TD]37856[/TD]
[TD]1[/TD]
[TD]853[/TD]
[TD]6951[/TD]
[TD]2356[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]11[/TD]
[TD]11/10[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]95[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]218[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]2372[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]2220[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]456[/TD]
[TD]35436[/TD]
[TD]1[/TD]
[TD]321[/TD]
[TD]2356[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="width: 64, align: right"]544[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]2[/TD]
[/TR]
</tbody>[/TABLE]


The formula I have is this (it doesn't work naturally - because it's applying a condition on results?)

=SUMPRODUCT(($B$2:$M$2="Season")*($B$1:$M$1=SHOW)*($A$3:$A$100>=START OF DATE RANGE)*($A$3:$A$100<=END OF DATE RANGE),$B$3:$M$100=1)



Results should be:



Between Dates

Start of Date Range: 9/22/2013
End of Date Range: 11/10/2013

"Show1"
Season: "1"

Count of episodes: 4



"Show2"
Season: "1"

Count of episodes: 8


"Show3"
Season: "2"

Count of episodes: 4
 
Oops, I forgot to change a few "Show1" references to the Name Show

My previous suggestion using names should read....
Code:
=SUMPRODUCT(
    INDEX(($B$1:$M$1=Show)*($B$2:$M$2="Season")*($B$3:$M$100=Season)*
       ($A$3:$A$100>=StartOfDateRange)*($A$3:$A$100<=EndOfDateRange),0,
       SUMPRODUCT(MATCH(1,($B$1:$M$1=Show)*($B$2:$M$2="Season"),0)))*
    ($B$1:$M$1=Show)*($B$2:$M$2=O10)*
    ($B$3:$M$100))

Revising your current formula should read...
(note that absolute references should be used so you can copy the formula down for the three Platforms).

Code:
=SUMPRODUCT(
      INDEX(($B$1:$M$1=$P$1)*($B$2:$M$2="Season")*($B$3:$M$100=$P$2)* 
      ($A$3:$A$100>=$P$4)*($A$3:$A$100<=$P$5),0,
      SUMPRODUCT(MATCH(1,($B$1:$M$1=$P$1)*($B$2:$M$2="Season"),0)))* 
      ($B$1:$M$1=$P$1)*($B$2:$M$2=O10)*($B$3:$M$100))




Thank you JS411!

It worked!!!

At first I was questioning the use of the MATCH formula (since it returns only the first instance)... and I was thinking that the --($B$3:$M$100=1) that DGYANG provided was the better.

If you could explain the match formula that would be great - just for my understanding please?


Again JS411 - thank you for all your help!
 
Upvote 0

Excel Facts

Will the fill handle fill 1, 2, 3?
Yes! Type 1 in a cell. Hold down Ctrl while you drag the fill handle.

Forum statistics

Threads
1,223,897
Messages
6,175,270
Members
452,628
Latest member
dd2

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