Help with a formula please - CountIf formula to return No. of HL instances in multiple cells

EmmaN

New Member
Joined
Jun 17, 2014
Messages
21
Hi all,

I'm trying to enter a Countif formula to add up the number of instances 'HL' appears in a number of cells across a row, but it keeps returning an error message, the error says i have used too many arguments for this function.

The formula i am trying to use is =COUNTIF(J3,R3,AA3,AJ3,AW3,BE3*"HL*")

iJRAAAJAWBE
2 Total number of HL Option 1 (IB Group 1)Option 2 (IB Group 2)Option 3 (Mixed IB Group)Option 4 (IB Group 4)Option 5 (IB Group 5)Option 6 (Mixed IB group)
3 =COUNTIF(J3,R3,AA3,AJ3,AW3,BE3*"HL*")

This should return 3
SL EnglishSL SpanishGroup 3: SL Business ManagementHL PhysicsHL MathematicsGroup 4: HL Chemistry
4 =COUNTIF(J4,R4,AA4,AJ4,AW4,BE4*"HL*")

This should return 3
SL English Language and LiteratureSL FrenchGroup 3: HL PsychologyHL Design & TechnologySL MathematicsGroup 4: HL Biology
5SL English Language and LiteratureHL SpanishGroup 3: SL EconomicsHL BiologySL MathematicsGroup 4: HL Chemistry

<tbody>
</tbody>

This is driving me nuts, It should be really easy but i cant get it to work. Thank you. Emma
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
on your criteria use "*"&HL&"*"

Code:
 [COLOR=#333333][FONT=Verdana]=COUNTIF(J3:AW3,[/FONT][/COLOR]"*"&HL&"*")
 
Last edited:
Upvote 0
on your criteria use "*"&HL&"*"

Code:
 [COLOR=#333333][FONT=Verdana]=COUNTIF(J3,R3,AA3,AJ3,AW3,[/FONT][/COLOR]"*"&HL&"*")


Hi, rickjason, thank you so much for your reply, however this still retunrs the error 'you've entered too many arguments for this function.

Emma
 
Upvote 0
Hi, rickjason, thank you so much for your reply, however this still retunrs the error 'you've entered too many arguments for this function.

Emma

Countif if for range of cell only not selected cells otherwise, you can use this one.

Code:
=IF(ISNUMBER(SEARCH("HL",J3)),1,0)+IF(ISNUMBER(SEARCH("HL",R3)),1,0)+IF(ISNUMBER(SEARCH("HL",AA3)),1,0)+IF(ISNUMBER(SEARCH("HL",AJ3)),1,0)+IF(ISNUMBER(SEARCH("HL",AW3)),1,0)+IF(ISNUMBER(SEARCH("HL",BE3)),1,0)
 
Last edited:
Upvote 0
If the other headings in row 2 do not contain the text "Option" then ..
- If you are using Excel 2010 or later
=COUNTIFS(J$2:BE$2,"*Option*",J3:BE3,"*HL*")

- or for any version of Excel
=SUMPRODUCT(--ISNUMBER(SEARCH("Option",J$2:BE$2)),--ISNUMBER(FIND("HL",J3:BE3)))
 
Upvote 0
Countif if for range of cell only not selected cells otherwise, you can use this one.

Code:
=IF(ISNUMBER(SEARCH("HL",J3)),1,0)+IF(ISNUMBER(SEARCH("HL",R3)),1,0)+IF(ISNUMBER(SEARCH("HL",AA3)),1,0)+IF(ISNUMBER(SEARCH("HL",AJ3)),1,0)+IF(ISNUMBER(SEARCH("HL",AW3)),1,0)+IF(ISNUMBER(SEARCH("HL",BE3)),1,0)


Perfect, Thank you so much for your help. Emma
 
Upvote 0
If the other headings in row 2 do not contain the text "Option" then ..
- If you are using Excel 2010 or later
=COUNTIFS(J$2:BE$2,"*Option*",J3:BE3,"*HL*")

- or for any version of Excel
=SUMPRODUCT(--ISNUMBER(SEARCH("Option",J$2:BE$2)),--ISNUMBER(FIND("HL",J3:BE3)))
Just to clarify, it doesn't have to be the word Option. If there is anything in the headings of these 'columns of interest' that does not appear in row 2 of any of the in-between columns (eg "Group" or just "(") then that could be used in either of my formulas instead of "Option".


If, for some reason you are forced to use the much longer way of checking individual cells, or you just choose to do that, the suggested formula can be written more simply as
Code:
=ISNUMBER(SEARCH("HL",J3))+ISNUMBER(SEARCH("HL",R3))+ISNUMBER(SEARCH("HL",AA3))+ISNUMBER(SEARCH("HL",AJ3))+ISNUMBER(SEARCH("HL",AW3))+ISNUMBER(SEARCH("HL",BE3))
 
Upvote 0

Forum statistics

Threads
1,214,938
Messages
6,122,346
Members
449,080
Latest member
Armadillos

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