record current position before leaving worksheet

rjplante

Well-known Member
Joined
Oct 31, 2008
Messages
503
I have a workbook with several worksheets on it. I would like to have on each worksheet a short piece of code that will record the current position of the selected cell before I leave the worksheet (select a different sheet) so that when the sheet is activated again, another piece of code will select the last cell the user was in. I currently have VBA code that selects a set of columns and then zooms so that those columns fill the window (Macro 1 below). When the user navigates back to the worksheet, the whole page is selected because of my zoom macro code in Macro 1. To resolve this issue, I would like to have the last known position of the user selected and then scroll to that row minus 5 rows. When I navigate to another worksheet, the value that get entered into cell BA1 from Macro 2 is the value of the current active cell in the worksheet I just activated, not the address of the active cell in the worksheet I just left (deactivated).

How do I record the current active cell address in the active worksheet before I leave the worksheet and select/activate/navigate to another worksheet?

If I can execute the zoom operation in Macro 1 without selecting the range, that would work to solve the problem.

Macro 1
VBA Code:
Private Sub Worksheet_Activate()

ActiveWindow.ScrollColumn = 1
'ActiveWindow.ScrollRow = 1

ActiveSheet.Range("A:F").Select
ActiveWindow.Zoom = True

'This is the code I want to implement
Range(Range("BA1").Value).Select
ActiveWindow.ScrollRow = Range("BA1").Row - 5

End Sub

Macro 2
Code:
Private Sub Worksheet_Deactivate()

Range("BA1").Value = ActiveCell.Address

End Sub
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,856
Office Version
  1. 365
Platform
  1. Windows
How about
VBA Code:
Private Sub Worksheet_Deactivate()
   Dim sht As Worksheet
   Set sht = ActiveSheet
   Application.EnableEvents = False
   Me.Activate
   Range("BA1").Value = ActiveCell.Address
   sht.Activate
   Application.EnableEvents = True
End Sub
 
Solution

rjplante

Well-known Member
Joined
Oct 31, 2008
Messages
503
Thanks, That works awesome!!

Quick question so that I can learn, what does the following line of code do?

Me.Activate

I have never encountered that before.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,856
Office Version
  1. 365
Platform
  1. Windows
It makes the sheet that contains the code the active sheet.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,856
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

Watch MrExcel Video

Forum statistics

Threads
1,130,118
Messages
5,640,216
Members
417,131
Latest member
Seanr19871

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top