×

VBA To Find The Last Cell With A Specific Fill Color

By Chris Newman •  Updated: 11/29/16 •  5 min read
Look for Last Cell Of Certain Color VBA Excel Spreadsheet Code

QUESTION

How can a find the last cell on a spreadsheet based on a given color?

SOLUTION

This VBA macro code allows you to select a cell with a specific fill color and it will automatically determine the last cell within your spreadsheet containing the designated fill color. The code uses an Inverse For Loop to cycle through each cell within the UsedRange of the spreadsheet in reverse order. There are three options provided to point your user to the resulting cell.

Sub FindLastColoredCell()
'PURPOSE: Determine Last Cell On Sheet Containing Specific Fill Color
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault

Dim TargetColor As Long
Dim cell As Range
Dim sht As Worksheet
Dim x As Long

'Choose target color based on currently selected cell
  TargetColor = ActiveCell.Interior.Color

'Inversely Loop Through Each Cell In Used Range on ActiveSheet
  For x = ActiveSheet.UsedRange.Cells.Count To 1 Step -1
    If ActiveSheet.UsedRange.Cells(x).Interior.Color = TargetColor Then
      'Notify User of Cell Address [Option 1]
        MsgBox "Last Color Found: " & ActiveSheet.UsedRange.Cells(x).Address
      
      'Select the last cell [Option 2]
        ActiveSheet.UsedRange.Cells(x).Select
      
      'Scroll To The Last Cell [Option 3]
        ActiveWindow.ScrollColumn = ActiveSheet.UsedRange.Cells(x).Column
        ActiveWindow.ScrollRow = ActiveSheet.UsedRange.Cells(x).Row
      
      'Exit Loop
        Exit Sub
    End If
  Next x

End Sub

Alternate (Better) Solution

Excel MVP Rick Rothstein submitted this alternative way to find the last colored cell. I like this solution as it is much shorter and I am assuming faster. 

Find Format

Rick’s macro essentially automates using the Find and Replace dialog functionality to search based on the active cell’s fill color format. Here’s the code:

Sub FindLastColoredCell()
'PURPOSE: Determine Last Cell On Sheet Containing Specific Fill Color
'AUTHOR: Rick Rothstein
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault

'Ensure Find Formatting Rule is Reset
  Application.FindFormat.Clear

'Store active cell's fill color into "Find"
  Application.FindFormat.Interior.Color = ActiveCell.Interior.Color

'Notify User of location using the "Find" Action
  MsgBox "Last Color Found: " & ActiveSheet.UsedRange.Find("", , , , , xlPrevious, , , True).Address

'Reset Find Formatting Rule
  Application.FindFormat.Clear

End Sub

Using VBA Code Found On The Internet

Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.

Getting Started Automating Excel

Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.

Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!

How Do I Modify This To Fit My Specific Needs?

Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it

I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).

I wish you the best of luck and I hope this tutorial gets you heading in the right direction!

Keep Learning

Chris Newman

Chris Newman

Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.

[FREE Training] 10 Amazing Excel Efficiency Tricks. Why Don't People Know These?!

X