Formula Help - Multiple COUNTIF's to validate if value is in range - Excel 2016

Johnny Thunder

Well-known Member
Joined
Apr 9, 2010
Messages
693
Office Version
  1. 2016
Platform
  1. MacOS
Hello All,

I have a formula that looks at 3 different sheets to validate if the value is in a range but I need help updating or using another method to enter the forumla.

Here is what I got so far but its not all the way there.

Formula: =IF(COUNTIF('Drama & Comedy'!$J$7:$L$33,"*"&E2&"*")>0=TRUE,"Backlog",IF(COUNTIF('Unscripted, Film, Kids'!$J$7:$L$33,"*"&E2&"*")>0=TRUE,"Backlog",IF(COUNTIF(Oprah!$J$7:$L$33,"*"&E2&"*")>0=TRUE,"Backlog","Grid")))

The jist of what is needed that is missing from the formula, is for each Countif that looks at different sheets, if the value is completely missing, mark it with "Not Available", If it is in range J7:L33 then "Backlog", if it is in range N7:T33 then "Grid".

I don't know how to enter the piece about "Not available" or how to modify what I currently have to suit.

Any help is appreciated. Also, the formula can't be an array formula since users won't be interacting with that sheet. Its something that I am flagging on the back end of the spreadsheet.
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Maybe:

=IF(SUMPRODUCT(COUNTIF(INDIRECT({"'Drama & Comedy'","'Unscripted, Film, Kids'","Oprah"}&"!J7:L33"),"*"&E2&"*")),"Backlog",IF(SUMPRODUCT(COUNTIF(INDIRECT({"'Drama & Comedy'","'Unscripted, Film, Kids'","Oprah"}&"!N7:T33"),"*"&E2&"*")),"Grid","Not Available"))
 
Upvote 0
Formula worked like a charm! Thanks for all the help on this. Got me past my roadblock.
 
Upvote 0

Forum statistics

Threads
1,213,567
Messages
6,114,342
Members
448,570
Latest member
rik81h

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