Macro to auto highlight a column if a cell contains specified value is in a row

KlayontKress

Board Regular
Joined
Jan 20, 2016
Messages
67
Office Version
  1. 2016
Platform
  1. Windows
To all,


I'm looking for a macro that will start in cell D6 and see if the cell contains the word "Custom" anywhere in the cell and if so, highlight the column to the last row with data in it. I then need it to move over to D6 and repeat until it encounters the last column with data with it at which point it will end. The number of options is variable so this may only gown down to F11 or it may go to F300 depending on the options a customer wants quoted.

In the chart below, the macro would start in D4 but it would only highlight from F4:F11.



Customer name
blah blah



Dateblah blah
Room nameStandard Room 1Standard Room 2Custom Room 3Standard Room 3
level 1$1.00$1.00$1.00$1.00$1.00
level 2$1.00$1.00$1.00$1.00
level 3$1.00$1.00$1.00$1.00
Option 1$1.00$1.00$1.00$1.00
Option 2$1.00$1.00$1.00$1.00
Option 3
$1.00$1.00$1.00$1.00$1.00

<tbody>
</tbody>






















Thanks in advance,
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Is the word "Custom" always in row 4?
 
Upvote 0
Try:
Code:
Sub highlightCol()
    Application.ScreenUpdating = False
    Dim LastRow As Long, val As Range
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Set val = Rows(4).Find("Custom", LookIn:=xlValues, lookat:=xlPart)
    If Not val Is Nothing Then
        Cells(4, val.Column).Resize(LastRow - 3, 1).Interior.ColorIndex = 6
    End If
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
I tried this code out and it works except that it stops after the first instance of custom. I probably should have specified that it's possible for multiple instances to appear. It also appears to highlight down to the bottom of the data in column A although this could be because of how the data is being exported into excel tha the cells in the highlighted column aren't truely blank even though they appear that they are. Is there a way to have it look to the last cell that has a value in the column being highlighted and then repeat until it encounters the last column with data?


Thanks again for helping with this.
 
Upvote 0
Try:
Code:
Sub highlightCol()
    Application.ScreenUpdating = False
    Dim LastRow As Long, val As Range, sAddr As String
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Set val = Rows(4).Find("Custom", LookIn:=xlValues, lookat:=xlPart)
    With Rows(4)
        Set val = .Find("Custom", LookIn:=xlValues, lookat:=xlPart, SearchOrder:=xlByColumns, SearchDirection:=xlNext)
        If Not val Is Nothing Then
            sAddr = val.Address
            Do
                Cells(4, val.Column).Resize(Cells(Rows.Count, val.Column).End(xlUp).Row - 3, 1).Interior.ColorIndex = 6
                Set val = .FindNext(val)
            Loop While val.Address <> sAddr
            sAddr = ""
        End If
    End With
    Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,251
Members
448,556
Latest member
peterhess2002

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