Conditional Formatting on blank cells only in Named Range

mattyg1406

New Member
Joined
Feb 6, 2015
Messages
10
I currently have a piece of code which applies some simple colour conditional formatting on blank cells on a set column on my workbook

:
Code:
       wsEmployeeData.Range("G" & LastEmployeeDataRow + 1 & ":G125").FormatConditions.Add Type:=xlExpression, Formula1:= _
           "=AND('" & wsEmployeeData.Name & "'!$C" & LastEmployeeDataRow + 1 & "<>"""",'" & wsEmployeeData.Name & "'!$G" & LastEmployeeDataRow + 1 & "<>"""")"
    
       wsEmployeeData.Range("G" & LastEmployeeDataRow + 1 & ":G125").FormatConditions(wsEmployeeData.Range("G" & LastEmployeeDataRow + 1 & ":G125") _
                                                      .FormatConditions.Count).SetFirstPriority
    
       With wsEmployeeData.Range("G" & LastEmployeeDataRow + 1 & ":G125").FormatConditions(1).Interior
           .PatternColorIndex = xlAutomatic
           .Color = RGB(0, 255, 255) ' Blue ( Optional )
           .TintAndShade = 0
       End With
    
       wsEmployeeData.Range("G" & LastEmployeeDataRow + 1 & ":G125").FormatConditions(1).StopIfTrue = False

I would like to make this code more dynamic, and use a named range reference for column G, as it is quite likely that additional columns may get added to the workbook in the future, and I don't want to have to keep amending my code.

I plan to use a named range for the "G9:G125" address, so the conditional formatting would need to find the first blank cell in the named range and apply formatting up to the end of the named range.

Does anyone have any suggestions to help me with this please?
 

Some videos you may like

Excel Facts

Will the fill handle fill 1, 2, 3?
Yes! Type 1 in a cell. Hold down Ctrl while you drag the fill handle.

Joe4

MrExcel MVP, Junior Admin
Joined
Aug 1, 2002
Messages
55,916
Office Version
  1. 365
Platform
  1. Windows
If your code already works, and the only issue is the range that it is being applied upon, just change all the Range references with your named range, i.e.
change:
Code:
Range("G" & LastEmployeeDataRow + 1 & ":G125")
with:
Code:
Range("MyRangeName")
where "MyRangeName" is whatever range name you have elected to use.
 

mattyg1406

New Member
Joined
Feb 6, 2015
Messages
10
Thanks Joe, but I need the formatting to be applied from the FIRST BLANK cell in the Named Range (rather than the start of the Named Range) and up to the LAST cell in the Named Range.
 

Joe4

MrExcel MVP, Junior Admin
Joined
Aug 1, 2002
Messages
55,916
Office Version
  1. 365
Platform
  1. Windows
Here is a block of code that should build the range you want for Conditional Formatting:
Code:
    Dim FirstBlankCell As String
    Dim LastCell As String
    Dim myCFRange As Range
    
'   Find first blank cell in a named range
    FirstBlankCell = Range("MyNamedRange").Cells.SpecialCells(xlCellTypeBlanks).Cells(1).Address
    
'   Find last cell in named range
    LastCell = Split(Range("MyNamedRange").Address, ":")(1)
    
'   Build range for conditional formatting
    Set myCFRange = Range(FirstBlankCell & ":" & LastCell)
 

Watch MrExcel Video

Forum statistics

Threads
1,122,577
Messages
5,596,996
Members
414,116
Latest member
sfullnet

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
Top