Conditional formatting based on list values with condition

Doge Robert

New Member
Joined
Jan 10, 2017
Messages
14
Greetings.
I have two tables, one with a column of customers (TblCustomer) and another table (TblCustomerTasks) with a column of customers (multiple occurances) and a column of tasks (single occurance for each customer).

I would like to have conditional formatting in a third table, where I can select the customer in column A and then the task in column B. If the task selected does NOT match one of the tasks sold to that customer in TblCustomerTasks, I need the cell to be highlighted red.

Is this possible? And if so, how?

An even better solution would be, if I could only select tasks, which where sold to a particular customer. So if I chose customer 1 in column A, then I could only select the tasks in the dropdown in column B, which where assigned to Customer 1 in TblCustomerTasks.

But it seems to me, that this may be beyond the limits of Excel... I am not certain.

What do you guys think?
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
what version of excel , if 2021 or 365 - you could do a dependant dropdown list using a filter - with a helper column - otherwise indirec() function

i have added all in 1 sheet - for ease of seeing here

so in
F3 - is a standard dropdown list - based on your customer table - datavalidation list

Then in column I i gave a helper list - so thats using
=SORT(FILTER($D$2:$D$13,$C$2:$C$13=$F$3),1)
which filters all the tasks based on the customer name and sorts in order of task name

then another dropdown - from the helper column - datavalidation list - But instead of range you just put =$I$2#
which looks at the array , that
=SORT(FILTER($D$2:$D$13,$C$2:$C$13=$F$3),1)

has created

Book2
ABCDEFGHI
1Table1sheet1Table2-sheet2Table3 - DropdownHelper
2customer-1task-1customerTasktask-2
3customer-1customer-1task-2customer-3task-3
4customer-2customer-1task-3task-4
5customer-3customer-1task-4task-5
6customer-1task-5
7customer-2task-1
8customer-2task-2
9customer-2task-3
10customer-3task-4
11customer-3task-5
12customer-3task-3
13customer-3task-2
Sheet1
Cell Formulas
RangeFormula
I2:I5I2=SORT(FILTER($D$2:$D$13,$C$2:$C$13=$F$3),1)
Dynamic array formulas.
Cells with Data Validation
CellAllowCriteria
F3List=$A$3:$A$5
G3List=$I$2#


will be only on dropbox for a few days

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.

This will possibly enable a quicker and more accurate solution for you.

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

Make sure you set any share or google to share to everyone
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,008
Messages
6,122,672
Members
449,091
Latest member
peppernaut

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