Selecting Non-Blank Cells In An Excel Column

What This VBA Code Does
The below VBA macro code will allow you to select only the cells in a stated column range that contain values or formulas. Note that if a formula outputs a blank value (ie “”) then it WILL NOT BE included in the selection, even thought the cell contains a formula. Scroll down to the next VBA snippet to include such formulas.
Sub SelectNonBlanks()
'PURPOSE: Selects only cells with values or formulas that do NOT output blank values (ie ="" or +"")
'SOURCE: www.TheSpreadsheetGuru.com
Dim rng As Range
Set rng = Range("A1:A10")
'Selecting only hardcoded data
rng.SpecialCells(xlCellTypeConstants).Select
'Selecting only formulas
rng.SpecialCells(xlCellTypeFormulas).Select
'Selecting hardcoded data and formulas
Union(rng.SpecialCells(xlCellTypeConstants), _
rng.SpecialCells(xlCellTypeFormulas)).Select
End Sub
What This VBA Code Does
The below VBA macro code will allow you to select only the cells in a stated column range that contain values or formulas. Note that if a formula outputs a blank value (ie “”) then it WILL BE included in the selection, even thought the cell contains a formula.
A special thanks to MrExcel MVP Rick Rothstein for showing me how to code the below subroutine.
Sub SelectNonBlankCells_ExcludingDoubleQuotes()
'PURPOSE: Selects only cells with values or formulas and excludes blank values (ie ="" or +"")
'AUTHOR: Rick Rothstein (MrExcel MVP)
'SOURCE: www.TheSpreadsheetGuru.com
Dim rng As Range
Dim UnusedColumn As Range
Set rng = Range("A1:A100")
'Find a column with nothing in it
Set UnusedColumn = Cells.Find("*", , xlFormulas, , xlByColumns, xlPrevious).EntireColumn.Offset(0, 1)
'Create temporary calculation column to determine which cells to select (marked by an X)
Intersect(rng.EntireRow, UnusedColumn) = Evaluate("IF(" & rng.Address & "="""","""",""X"")")
'Make Selection
Intersect(UnusedColumn.SpecialCells(xlConstants).EntireRow, rng.EntireColumn).Select
'Remove Temporary Blank Caluclations
UnusedColumn.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!
After 10+ years of creating macros and developing add-ins, I've compiled all the hacks I wish I had known years ago!

Keep Learning
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.