Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Storing a User's Location before Running a Macro.

Storing a User's Location before Running a Macro

Written by Allen Wyatt (last updated March 20, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


John has a macro that does some processing on various worksheets in a workbook. He wants, at the beginning of the macro, to save the range of cells (or the single cell) that the user has selected. He uses ActiveCell.Address to determine this. Then, at the end of the macro, he wants to return to the user with the same range selected that they originally had selected.

The problem is, the macro could be finished on an entirely different worksheet than where the user started, and ActiveCell.Address only gives a cell address, not a worksheet name and definitely not a range. John wonders about the best way to store what he needs so he can return to the user's original location at the end of the macro.

For the best chance of getting someone back to where they started, there are three elements: workbook, worksheet, and cell. Actually, this last element (cell) may be a bit simplistic, as the user will always have a cell selected (this is what is returned by ActiveCell.Address), but may additionally have a range selected.

Here's how you get all four items:

Dim rngOrigSelection As Range
Dim rngOrigCell As Range
Dim sOrigWS As String
Dim sOrigWB As String

Set rngOrigSelection = Selection
Set rngOrigCell = ActiveCell
sOrigWS = ActiveSheet.Name
sOrigWB = ActiveWorkbook.Name

When you want to later return the user to where they were, you can use this type of code:

Workbooks(sOrigWB).Activate
Sheets(sOrigWS).Select
rngOrigSelection.Select
rngOrigCell.Activate

Of course, Excel always has multiple ways that you can accomplish any given task. In this case, you could shorten your code by only remembering the active cell and selected range:

Dim rngOrigSelection As Range
Dim rngOrigCell As Range

Set rngOrigSelection = Selection
Set rngOrigCell = ActiveCell

When you want to restore the user to the location, you rely upon the Parent object available in VBA:

rngOrigSelection.Parent.Parent.Activate
rngOrigSelection.Parent.Select
rngOrigSelection.Select
rngOrigCell.Activate

The Parent object of the selection range you saved is the worksheet in which that range is located, and the Parent of that Parent object is the workbook in which the worksheet is located.

Another approach is to simply create, within your macro, a named range that refers to whatever the user had selected:

ActiveWorkbook.Names.Add Name:="MyOrigPlace", RefersTo:=Selection

After you do your processing, when you are ready to return to what the user had selected, you use this code:

Application.Goto Reference:="MyOrigPlace"
ActiveWorkbook.Names("MyOrigPlace").Delete

The first line returns to the selection and the second line then deletes the named range. The only drawback to this approach is that the active cell is not retained; the code assumes that you want the upper-left cell in the range to be the active cell when it is done. You should also be aware that if your processing deletes the cells that make up the named range, then the code may not work properly—Excel can't go to a place that no longer exists.

Of course, you may not have to remember any location at all, if you code your macro correctly. While VBA allows you to "move around" and select different areas of your worksheets and workbook, in most cases this isn't necessary. You could, for instance, simply work with different ranges and then do your work on those ranges, without ever changing the current selection or active cell. Indeed, VBA allows you to change, reformat, sort, delete, and do almost anything you can imagine to cells without actually needing to select them.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6161) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Storing a User's Location before Running a Macro.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

E-mailing PDF Reports Results in Consistent Crash

It is possible to create macros that send out reports, via e-mail, from within Excel. Frank did this and ran into ...

Discover More

Saving Your Work Automatically

Word can be configured to save your work periodically; on any time schedule you desire. This tip explains this feature ...

Discover More

Heading Changes for Multi-page Tables

When you have a long table that extends over multiple pages, Word allows you to specify one or more rows to be repeated ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Inserting Worksheet Values with a Macro

Macros are often used to process information in a worksheet. You may need your macro to change the values stored in ...

Discover More

Recording a Macro

One of the most common ways of creating macros is to use Excel's macro recorder. This tip shows how easy it is to use the ...

Discover More

Opening a Workbook and Suppressing Automatic Macros

Want to stop Excel from running any automatic macros that may be stored with a workbook? Here's how to do it.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two more than 9?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.