Conditional Formatting based on a cell with data separated by commas

Technovice

New Member
Joined
Jan 12, 2023
Messages
6
Office Version
  1. 2019
Platform
  1. Windows
Hello,
I need some assistance with conditional formatting whilst using the index and match function. I would like cells in table 2 (on the right) to change colour when the first and second columns align with the boxes marked with X in the table on the left. I have managed to do this for cells in columns H and I where there is a single word, but it won't work for cells where there are multiple entries separated by a comma.
As an example, the formula I have used to match in conditional formatting for entries in column H to Column J (orange color) is: =IF(INDEX($A$2:$F$7,MATCH($H2,$A$2:$A$7,0),2)="X","TRUE")
To match Column I to column J (blue color), the formula is:
=IF(INDEX($A$2:$F$7,MATCH($I2,$A$2:$A$7,0),2)="X","TRUE")
I have been unable to get the formula to recognize when a word from column A is is present but separated by a comma in column I (e.g. in I10)
Any assistance would be greatly appreciated.


excelpic1.png
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Hi and welcome to MrExcel!

The following formulas also consider the name in each column.

Dante Amor
ABCDEFGHIJKLMN
1FruitJackMelSamTomJakeFruit 1Fruit 2JackMelSamTomJake
2BananaXXBanana
3WatermelonXXXWatermelonBanana
4OrangesXApple
5MandarineXXBanana
6FigXFigBanana
7PearXFigBanana
8Apple
9Banana
10MandarineOranges, Pear
11WatermelonOranges
12FigBanana
Hoja1
Cells with Conditional Formatting
CellConditionCell FormatStop If True
J2:N12Expression=SUMPRODUCT(($A$2:$A$7=$H2)*($B$1:$F$1=J$1)*($B$2:$F$7="X"))textNO
J2:N12Expression=SUMPRODUCT((ISNUMBER(SEARCH(","&$A$2:$A$7&",",","&SUBSTITUTE($I2," ","")&",")))*($B$1:$F$1=J$1)*($B$2:$F$7="X"))textNO
 
Upvote 0
Solution
Thankyou so much, it seems to work when I copied it over, except for the Jack column remains empty? I have selected the correct cells to apply the formula to so I am not sure why?
Exceltest1.png
Exceltest2.png
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,329
Members
452,635
Latest member
laura12345

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