Looking for a more elegant way to write the following countifs formula

willow1985

Well-known Member
Joined
Jul 24, 2019
Messages
735
Office Version
  1. 365
Platform
  1. Windows
Hello,

was wondering if anyone could help me with the below formula. Is there a more elegant way of writing it rather than adding each additional section?

I want the formula to count E:E if it matches Z2, and if S:S matches B12, C12 and D12. Would this be some sort of Countifs/And formula?

=COUNTIFS('WO Report'!$E:$E,Z2,'WO Report'!$S:$S,$B$12)+COUNTIFS('WO Report'!$E:$E,Z2,'WO Report'!$S:$S,$C$12)+COUNTIFS('WO Report'!$E:$E,Z2,'WO Report'!$S:$S,$D$12)

Thank you for all of your help :)

Carla
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop

Special-K99

Well-known Member
Joined
Nov 7, 2006
Messages
8,416
Not much more elegant, think you got it about as good as its gonna get. This is pretty much the same

=SUMPRODUCT(('WO Report'!E:E=Z2)*(('WO Report'!S:S=B12)+('WO Report'!S:S=C12)+('WO Report'!S:S=D12)))
 

willow1985

Well-known Member
Joined
Jul 24, 2019
Messages
735
Office Version
  1. 365
Platform
  1. Windows
=COUNTIFS('WO Report'!$E:$E,Z2,'WO Report'!$S:$S,$B$12,'WO Report'!$S:$S,$C$12,'WO Report'!$S:$S,$D$12)

This formula does not work but is there a reason why?

the reason I ask is that this formula works in another workbook I have and I thought the conditions were the same.

The other workbook where the formula works:

=COUNTIFS(Report!$M:$M,A7,Report!$A:$A,'Weekly Metrics'!$B$4,Report!$P:$P,'Weekly Metrics'!$D$4)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,562
Office Version
  1. 365
Platform
  1. Windows
The countifs function works on an AND basis, so you are looking for any cell in col S that matches B12 & C12 & D12.
So unless B12,C12 & D12 are all the same value, the formula will give you 0.
 

pgc01

MrExcel MVP
Joined
Apr 25, 2006
Messages
19,884
=COUNTIFS('WO Report'!$E:$E,Z2,'WO Report'!$S:$S,$B$12,'WO Report'!$S:$S,$C$12,'WO Report'!$S:$S,$D$12)

This formula does not work but is there a reason why?

What you are saying is that you want

'WO Report'!$S:$S

to be equal to $B$12 AND to be equal to $C$12 AND to be equal to $D$12

and I think you want OR, not AND

Try instead:

=SUMPRODUCT(COUNTIFS('WO Report'!$E:$E,Z2,'WO Report'!$S:$S,$B$12:$D$12))
 

willow1985

Well-known Member
Joined
Jul 24, 2019
Messages
735
Office Version
  1. 365
Platform
  1. Windows
That works. Thank you very much :)
 

Forum statistics

Threads
1,141,707
Messages
5,707,979
Members
421,539
Latest member
zuniBM

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
Top