Written by Allen Wyatt (last updated October 10, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Kris has a worksheet where there are a large number of blank rows in the data. He's looking for a simple macro that will delete all the rows that are totally blank.
There are a number of ways to accomplish this task. The following sections examine all the various ideas for getting rid of those troublesome rows.
Selecting Blanks
One quick way you can check where blanks are is to just select blanks in your data. Follow these steps:
Figure 1. The Go To Special dialog box.
There is a huge caveat in taking this approach: It will delete any rows in which any cell is blank. In other words, this approach is best if the only blanks in your data are in rows that you actually want to delete. If there are some empty cells interspersed among data you really want to keep, don't use this method, as it will delete those rows, as well.
Sorting
If your data doesn't consist of very many rows (say, only ten columns or fewer), you might consider just sorting the data. If you include each column in your sort specification, then you'll end up with the blank rows all right next to each other and you can easily delete them.
If there are lots of columns in your data and you don't mind adding a helper column, you can get rid of blank rows in a variation on the sorting method. Let's say that your data is in column A through P. In column Q, enter either one of these formulas:
=COUNTA(A1:P1) =IF(COUNTBLANK(A1:P1)=16,"DELETE","")
It doesn't matter which one you use; they will both give you information you can work with. In the case of the COUNTA formula, you simply need to sort on the basis of column Q and delete anything with a 0 in that column.
In the case of the COUNTBLANK formula, you'll want to change the equated value (16) to however many columns you are having the COUNTBLANK function consider. (In this case, 16 is the number of columns in the range A:P, inclusive.) After the formula is in place you can sort by column Q, then simply delete all the rows that have the word "DELETE" in that column.
Another variation on the sorting approach is to simply use the filtering capabilities of Excel to filter your list to contain only blanks in one of the data columns. (For instance, you might filter for blanks in column A.) You can then sort the remaining columns so you have entire blank rows in one place and then delete those rows.
Macros
If you need to delete blank rows quite often, then you'll want to seriously consider using a macro to do the hard work. Your macro could easily be added to the ribbon or assigned to a shortcut key so you can invoke it very easily.
Earlier in this tip I mentioned that you could, if desired, use the Go To Special dialog box to select blank cells in the range of your data and then delete the rows on which those blank cells occur. You can do the same thing in a ver simple macro:
Sub DeleteBlanks() Dim R As Range Set R = Range("A1:" & ActiveCell.SpecialCells(xlLastCell).Address) R.SpecialCells(xlCellTypeBlanks).EntireRow.Delete End Sub
Remember, though, that this macro will delete any rows on which there are any blanks, even if you want to keep other data that may be on that row.
A better approach would be to do a more comprehensive check on each row in the worksheet:
Sub DeleteBlankRows() Dim lRows As Long Dim J As Long lRows = ActiveCell.SpecialCells(xlLastCell).Row Application.ScreenUpdating = False For J = lRows To 1 Step -1 If WorksheetFunction.CountA(Rows(J)) = 0 Then Rows(J).Delete Next J Application.ScreenUpdating = True End Sub
Note that the macro determines the last cell used in the workbook and sets the lRows value equal to the row on which that cell occurs. A For...Next loop then steps through each row (from the last to the first) and uses the COUNTA function to determine if there is anything on that row. If not, the row is deleted.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (254) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Import information from a program external to Excel, and your numbers may be treated as text because of the way that the ...
Discover MoreYour worksheets are very often made up of formulas and these formulas are made up of functions. If you ever want to ...
Discover MoreIt can be frustrating when you get error messages doing something that you previously did with no errors. If you get an ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-04-29 08:51:37
Joan Koskela
For step 1, if there is one column that contains something in every row you want to keep, select that column instead of all of the data and proceed with the remaining steps.
2018-08-14 09:16:54
John 41
There is a possible problem with the 1st method - using the Goto Special and using the "Blanks" option. If some of the rows of data you want to keep also contain some blank cells, these will also be selected, and when the Delete tool o n the Home tab is used,m these cells will be deleted resulting in all data to the right of these cells being shifted left by the number of cells deleted. This will very likely be a highly undesirable result. To avoid this hapening, when don't click the Delete tool, instead click the drop-down arrow on the on the bottom of the Delete tool, then click the option "Delete Rows"
2018-08-12 16:45:37
Ruthie
@Alex B
For a larger data set, you can use a formula in one column of your data to check if the rest of the row is empty instead of the conditional formatting. Or amend a macro to remove the formatting for you. I suggested the conditional formatting as an interim method to make sure that only the rows you wanted deleted are actually the ones to be deleted. If the highlight hits on a row you want to keep, you know something's off. I backup whatever I'm working on just in case, but checking to be sure things go as planned is an extra layer of insurance of not having to do them over!
2018-08-11 19:56:12
Alex B
@Ruthie
You may want to consider that conditional formatting is regarded as volatile. It is likely to not only be quite slow if you use it on a large dataset but will also leave you with an unnecessary overhead if you don't remove it after you have completed the delete process. (it will still be applied to the undeleted rows)
2018-08-11 08:01:44
Ruthie
Manual process
Another way to delete only blank rows using a filter and conditional formatting:
Set up a condition to color one cell in the row if the entire row is blank
Filter your data to show the colored cells.
Delete those rows.
Unfilter your data.
Automated process:
Once you have the above process working to your satisfaction, turn it into a macro. Then assign it to a keyboard shortcut, a button on your QAT, or an image in your file for easy access.
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments