Countifs with a ranged area and multiple criteria

davekent10

New Member
Joined
Apr 11, 2014
Messages
3
Hi,

Been looking through this form and can find a solution to this, so hoping that someone might have one for me.

I'm using a COUNTIFS statement with multiple criteria. Use 2 sheets, 1st is call "Master" which has all the data, second is "Reports", which has all the formulas.

I'm trying to use the following formula:
=(COUNTIFS(Master!$E$2:$E$5000,C$1,Master!$U$2:$U$5000,$A$1,Master!V2:AV5000,$A$2,Master!$S$2:$S$5000,$B2))

Everything is straight forward except this part Master!V2:AV5000,$A$2
The value for Cell A2 is random value, that appears in columns on the Master sheet V through AV

The current value for A2 is equal to the values in Master!AG column, so when I change the formula to
=(COUNTIFS(Master!$E$2:$E$5000,C$1,Master!$U$2:$U$5000,$A$1,Master!AG2:AG5000,$A$2,Master!$S$2:$S$5000,$B2))

It returns the correct count. I would love to keep this, but since A2 changes each week, it's either I have to change the formula each week or go crazy.

I've tried defining a name for the range of Master!AG2:AG5000 with no luck

And advice or recommendations is welcome, I have no problem changing the entire formula as long as I get the correct output.

If more information is required, please let me know!

Thank you.
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Yes, each heading is the same as the value of each column, which is fixed and will never change. Headings for V, W, and Y in bold.

CommunicationLine of FireBalance/Traction/Grip
CommunicationLine of Fire
CommunicationBalance/Traction/Grip

<tbody>
</tbody>
 
Last edited:
Upvote 0
Yes, each heading is the same as the value of each column, which is fixed and will never change. Headings for V, W, and Y in bold.

Communication
Line of Fire
Balance/Traction/Grip
Communication
Line of Fire
Communication
Balance/Traction/Grip

<TBODY>
</TBODY>

Try...
Rich (BB code):
=COUNTIFS(
  Master!$E$2:$E$5000,C$1,
  Master!$U$2:$U$5000,$A$1,
  INDEX(Master!V2:AV5000,0,MATCH($A$2,Master!V1:AV1,0)),$A$2,
  Master!$S$2:$S$5000,$B2)
 
Upvote 0

Forum statistics

Threads
1,215,430
Messages
6,124,849
Members
449,194
Latest member
HellScout

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