Countifs in two dimensional array, repeating header (non unique)

emichan

New Member
Joined
Sep 11, 2014
Messages
22
Hello,

I have a table like this:
FY2014FY2015Count?
TickerQ1Q2Q3Q4Q1Q2Q3Q4Q1Q2Q3Q4
A8/13/1411/13/142/13/146/26/148/14/1511/13/152/13/152221
B8/9/151411/14/142/13/146/26/148/7/1511/13/152/14/156/13/152222
C2/12/135/10/138/9/1412/13/142/10/155/9/152211

<tbody>
</tbody>
I'm trying to count how many inputs i have for particular ticker, for particular quarter, with no regard to year.
That is, I want to get an output that shows for
A, Q1= 2
B, Q4= 2
C, Q3= 1

I tried getting a pivot table, but the problem is i don't have unique header names, so I get Q1, Q2, Q3, Q4 and then Q12, Q22, etc...

Is there a way to get countif which looks up criteria range, criteria, and count range, like sumifs?

Thank you!!
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Which version of Excel are you using?
For XL2007+, try

=COUNTIFS($B$2:$I$2,"Q1",INDEX($B$2:$I$4,MATCH("A",$A$2:$A$4,0),0),"<>")
 
Last edited:
Upvote 0
Or based on the cell references for A and Q1

=COUNTIFS($B$2:$I$2,K$2,$B3:$I3,"<>")
 
Last edited:
Upvote 0
Try the countifs (i did have to adjust the ranges a bit)


Unknown
ABCDEFGHIJKLM
1FY2014FY2015Count?
2TickerQ1Q2Q3Q4Q1Q2Q3Q4Q1Q2Q3Q4
3A08/13/201411/13/201402/13/201406/26/201408/14/201511/13/201502/13/20152221
4B8/9/151411/14/201402/13/201406/26/201408/07/201511/13/201502/14/201506/13/20152222
5C02/12/201305/10/201308/09/201412/13/201402/10/201505/09/20152211
Sheet1
Cell Formulas
RangeFormula
J3=COUNTIFS($B$2:$I$2,J$2,$B3:$I3,"<>")
J4=COUNTIFS($B$2:$I$2,J$2,$B4:$I4,"<>")
J5=COUNTIFS($B$2:$I$2,J$2,$B5:$I5,"<>")
K3=COUNTIFS($B$2:$I$2,K$2,$B3:$I3,"<>")
K4=COUNTIFS($B$2:$I$2,K$2,$B4:$I4,"<>")
K5=COUNTIFS($B$2:$I$2,K$2,$B5:$I5,"<>")
L3=COUNTIFS($B$2:$I$2,L$2,$B3:$I3,"<>")
L4=COUNTIFS($B$2:$I$2,L$2,$B4:$I4,"<>")
L5=COUNTIFS($B$2:$I$2,L$2,$B5:$I5,"<>")
M3=COUNTIFS($B$2:$I$2,M$2,$B3:$I3,"<>")
M4=COUNTIFS($B$2:$I$2,M$2,$B4:$I4,"<>")
M5=COUNTIFS($B$2:$I$2,M$2,$B5:$I5,"<>")
 
Upvote 0

Forum statistics

Threads
1,213,527
Messages
6,114,150
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