Countif with multiple criteria

vladi305

Board Regular
Joined
Jan 12, 2023
Messages
88
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
this worksheet checks that values on the range from A:E all the way down to match the one from G:K on the first row

I tried using COUNTIFS, MATCH with SUM, SUMPRODUCT and the best I could do was hardcoding the array. It will be productive to change this to check the values from G to K dinamically and not hardcode as it is
Any ideas to improve this formula?

=IF(SUM(COUNTIF(A1:E1,{"8","19","26","27","34"}))=5,$L$1,
IF(SUM(COUNTIF(A1:E1,{"8","19","26","27","34"}))=4,$M$1,
IF(SUM(COUNTIF(A1:E1,{"8","19","26","27","34"}))=3,$N$1,
IF(SUM(COUNTIF(A1:E1,{"8","19","26","27","34"}))=2,$O$1,
IF(SUM(COUNTIF(A1:E1,{"8","19","26","27","34"}))<2,"L","F")))))
 

Attachments

  • Pic51.jpg
    Pic51.jpg
    131.5 KB · Views: 21

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
the "8" is looking for text , not a number
perhaps a sumproduct
=SUMPRODUCT(--(A1:E1=G1:K1))
within the IF()

BUT you say you tried that already - or at least sumproduct

Note: Images are difficult to see , and also requires that I input all the data myself, which means I may make an error, which is very time consuming, and from my point of view less likely to get a response, if a complicated spreadsheet. Plus we cannot see any of the formulas used.

Therefore -

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.

MrExcel has a tool called “XL2BB” that lets you post samples of your data and will allow us to copy/paste your sample data into our Excel spreadsheets, saving a lot of time.

You can also test to see if it works ok, in the "Test Here" forum.

OR if you cannot get XL2BB to work, or have restrictions on your PC , then put the sample spreadsheet onto a share
I only tend to goto OneDrive, Dropbox or google docs , as I'm never certain of other random share sites and possible virus.
Please make sure you have a representative data sample and also that the data has been desensitised, remember this site is open to anyone with internet access to see - so any sensitive / personal data should be removed
 
Upvote 0
This formula in cell F1 then copy and paste formula for the rest of the rows in column F.

=IF(AND(A1=$G$1,B1=$H$1,C1=$I$1,D1=$J$1,E1=$K$1),"F","L")
 
Upvote 0
This formula in cell F1 then copy and paste formula for the rest of the rows in column F.

=IF(AND(A1=$G$1,B1=$H$1,C1=$I$1,D1=$J$1,E1=$K$1),"F","L")
I may have reversed the "F" and the "L" for your application.
 
Upvote 0
Try this ARRAY formula.
Excel Formula:
=IF(SUM(COUNTIF(A1:E1,{"8","19","26","27","34"}))={5,4,3,2,1},$L$1:$O$1,IF(SUM(COUNTIF(A1:E1,{"8","19","26","27","34"}))<2,"L","F"))
To enter ARRAY formula
Copy and paste the formula in cell
Press F2
Press Ctrl+Shift+Enter together
Excel covers the formula with {}.
 
Upvote 0
not sure if this is what you're looking for. I would arrange your Excel like the one below.

Mrexcel.xlsm
ABCDEFGHIJKLMNOP
11871920Free Ticket1821273212345
21271922LLFree Ticket11148.589000
31271926L
41271932Free Ticket
51271934L
61272021Free Ticket
71272122Free Ticket
81272126Free Ticket
9127213211
101272134Free Ticket
Sheet1
Cell Formulas
RangeFormula
F1:F10F1=IFERROR(INDEX($L$1:$P$2,2,MATCH(SUM(COUNTIF(A1:E1,$G$1:$K$1)),$L$1:$P$1,0)),"F")
 
Upvote 0
Solution
Formula in Post#5 may not work in many conditions.
Assuming that A1:E1 are numbers not strings.
Try
=IFERROR(INDEX($L$1:$O$1,MATCH(SUM(COUNTIF(A1:E1,{8,19,26,27,34})),{5,4,3,2},0)),IF(SUM(COUNTIF(A1:E1,{8,19,26,27,34}))<2,"L","F"))
 
Upvote 0
Ty guys, I'll try some of the modified formulas here, the one I have works fine but it's hardcoded and numbers need to be inputed every time on a daily basis
 
Upvote 0
not sure if this is what you're looking for. I would arrange your Excel like the one below.

Mrexcel.xlsm
ABCDEFGHIJKLMNOP
11871920Free Ticket1821273212345
21271922LLFree Ticket11148.589000
31271926L
41271932Free Ticket
51271934L
61272021Free Ticket
71272122Free Ticket
81272126Free Ticket
9127213211
101272134Free Ticket
Sheet1
Cell Formulas
RangeFormula
F1:F10F1=IFERROR(INDEX($L$1:$P$2,2,MATCH(SUM(COUNTIF(A1:E1,$G$1:$K$1)),$L$1:$P$1,0)),"F")
I'll use this method. I tried 4 and it didn't work and #5 is using hardcode numbers on the array so hajiali method was the best choice for my application. Again, thank you guys!
 
Upvote 0
the "8" is looking for text , not a number
perhaps a sumproduct
=SUMPRODUCT(--(A1:E1=G1:K1))
within the IF()

BUT you say you tried that already - or at least sumproduct

Note: Images are difficult to see , and also requires that I input all the data myself, which means I may make an error, which is very time consuming, and from my point of view less likely to get a response, if a complicated spreadsheet. Plus we cannot see any of the formulas used.

Therefore -

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.

MrExcel has a tool called “XL2BB” that lets you post samples of your data and will allow us to copy/paste your sample data into our Excel spreadsheets, saving a lot of time.

You can also test to see if it works ok, in the "Test Here" forum.

OR if you cannot get XL2BB to work, or have restrictions on your PC , then put the sample spreadsheet onto a share
I only tend to goto OneDrive, Dropbox or google docs , as I'm never certain of other random share sites and possible virus.
Please make sure you have a representative data sample and also that the data has been desensitised, remember this site is open to anyone with internet access to see - so any sensitive / personal data should be removed
This formula worked fine as well, sorry I didn't try it before, I was looking at getting the complete formula and not just the counting
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,471
Messages
6,124,999
Members
449,201
Latest member
Lunzwe73

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