Written by Allen Wyatt (last updated January 7, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003
Diane wrote about a problem she was having with a file imported into Excel. The file, created by a non-Excel program, contains 50,000 records, but only the first 87 records contain any data. When the file is imported, pressing Ctrl+End moves to cell J50000 instead of cell J87. Diane was wondering how to make Excel jump to the end of the real data—J87.
The first thing to try is to simply save your workbook, get out of Excel, and then reopen the workbook. Doing so "resets" the end-of-data pointer in the workbook, and you should be fine.
If that doesn't solve the problem, then it is very likely that the data you imported into Excel included non-printing characters, such as spaces. If these are loaded into cells, Excel sees them as data, even though you don't. To fix the workbook by deleting the data, select row 88 (the one right after your data) and then hold down the Shift and Ctrl keys as you press the Down Arrow. All the rows from 88 through the last row in th worksheet should be selected. Press the Delete key, save the workbook, and reopen it. Ctrl+End should work fine.
If you have quite a few of these files you need to "clean up," or if you need to do it on a regular basis, then you need a macro to help you. Consider the following macro:
Sub ClearEmpties() Dim c As Range Dim J As Long J = 0 Selection.SpecialCells(xlCellTypeConstants, 23).Select For Each c In Selection.Cells J = J + 1 StatusBar = J & " of " & Selection.Cells.Count c.Value = Trim(c.Value) If Len(c.Value) = 0 Then c.ClearFormats End If Next StatusBar = "" End Sub
This macro selects all the cells in the worksheet that contain constants (in other words, they don't contain formulas). It then steps through each of those cells and uses the Trim function to remove any leading or trailing spaces from the contents. If the cell is then empty, any formatting is cleared from the cell.
When the macro is done, you can save and close the workbook, reopen it, and you should be able to use Ctrl+End to go to the real end of your data. If this still doesn't work, it means that the cells being imported into the workbook have some other invisible, non-printing character in them. For instance, there could be some bizarre control characters in the cells. In this case, you need to talk with whoever is creating your import file. The best solution, at this point, would be for the person to modify their program so it doesn't include the "trash" that Excel is mistaking for valid cell content.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3297) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Jumping to the Real Last Cell.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Want a quick way to get to the last cell in your worksheet? This tip provides a handy shortcut and a potential "gotcha."
Discover MoreNeed a quick way to jump to a particular part of your worksheet? You can do it by using the Go To dialog box.
Discover MoreWhen you select a range of cells (particularly if it is a large range of cells), you may not be quite sure if you've ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments