Complex Countifs/Index/Match/Array?

towners

Board Regular
Joined
Mar 12, 2009
Messages
225
Office Version
  1. 365
Platform
  1. Windows
Hi,

I could do with some help to work out how to calculate from the example below: (sorry I don't know how to paste image/worksheet).

Month Jan Jan Jan Jan Feb Feb Feb Feb
Apples 4 4 5 4 5 2 4 5
Pears 2 1 3 2 2 1 3 2

I would like to use a formula to show:

Apples sold in month & Pears sold in month.

Can anyone point me in the right direction?

Thanks

Towners
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Hello,

If your months are formatted as dates, the select whole data.
Copy / paste special and transpose to a different location
Select the copied data and insert a pivot table

MonthApplePears
janv-1542
janv-1541
janv-1553
janv-1542
févr-1552
févr-1521
févr-1543
févr-1552

<tbody>
</tbody>


Pivot table result =
Row LabelsSum of AppleSum of Pears
janv-15178
févr-15168
Grand Total3316

<tbody>
</tbody>
 
Upvote 0
And here is my version...


Excel 2010
ABCDEFGHI
1JanJanJanJanFebFebFebFeb
2Apples44545345
3Pears21322132
4
5JanFeb
6Apples1717
7Pears88
Sheet5
Cell Formulas
RangeFormula
B6=SUMPRODUCT($B$2:$I$3*($B$1:$I$1=B$5)*($A$2:$A$3=$A6))
B7=SUMPRODUCT($B$2:$I$3*($B$1:$I$1=B$5)*($A$2:$A$3=$A7))
C6=SUMPRODUCT($B$2:$I$3*($B$1:$I$1=C$5)*($A$2:$A$3=$A6))
C7=SUMPRODUCT($B$2:$I$3*($B$1:$I$1=C$5)*($A$2:$A$3=$A7))
 
Upvote 0
Try...

=SUMIFS(INDEX($B$2:$I$3,MATCH("apples",$A$2:$A$3,0)),$B$1:$I$1,"jan")

The formula misses an important piece. Here is the full version...

Row\Col
A​
B​
C​
D​
E​
F​
G​
H​
I​
J​
K​
L​
M​
1​
MonthJanJanJanJanFebFebFebFebjanfeb
2​
Apples
4​
4​
5​
4​
5​
2​
4​
5​
apples
17
16
3​
Pears
2​
1​
3​
2​
2​
1​
3​
2​
pears
8
8

L2, copied across and down:

=SUMIFS(INDEX($B$2:$I$3,MATCH($K2,$A$2:$A$3,0),0),$B$1:$I$1,L$1)
 
Upvote 0
Hi Aladin,

That is exactly the result and formula I was looking for. Now I can combine this with my dynamic named ranges and it's a smart little function.

Regards

Towners
 
Upvote 0

Forum statistics

Threads
1,213,527
Messages
6,114,148
Members
448,552
Latest member
WORKINGWITHNOLEADER

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