Find name of previous sheet

JC2710

Board Regular
Joined
Mar 10, 2008
Messages
164
Hi

When I select a sheet within a workbook, within the Activate Event I want to be able to know which sheet was the previous sheet selected before the user selected the current sheet.

Is there any way of doing this?

Thanks
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)

Colin Legg

MrExcel MVP
Joined
Feb 28, 2008
Messages
3,497
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Best to monitor this at the workbook level.

Before the 'next' sheet's activate event is raised, the 'current' sheet's deactivate event is raised.

eg. In the ThisWorkbook Class Module:
Code:
Private pPreviousSheet As Object
 
Private Sub Workbook_SheetActivate(ByVal Sh As Object)
    If Not pPreviousSheet Is Nothing Then MsgBox pPreviousSheet.Name & " deactivated"
    MsgBox Sh.Name & " activated"
End Sub
 
Private Sub Workbook_SheetDeactivate(ByVal Sh As Object)
    Set pPreviousSheet = Sh
End Sub
 
Upvote 0

Domski

Well-known Member
Joined
Jan 18, 2005
Messages
7,292
My effort, again at a workbook level:

Code:
Private Sub Workbook_SheetActivate(ByVal Sh As Object)
Static previousSheet As String
Static currentSheet As String
If currentSheet = "" Then
    currentSheet = ActiveSheet.Name
Else
    previousSheet = currentSheet
    currentSheet = Sh.Name
End If
MsgBox previousSheet
End Sub

Dom
 
Upvote 0

pgc01

MrExcel MVP
Joined
Apr 25, 2006
Messages
19,892
Another way is to split this in two.

- At the workbook level you just store the previous worksheet and make it available as a new property of the workbook.

- At the worksheet level you use your Activate event procedure as usual. The difference is that you can now use a new property of the workbook that gives you the previous worksheet selected.

Remark: If you think it's possible that you work with several windows for the same workbook in the same instance of excel, don't forget to adapt the solutions.
 
Upvote 0

Captain Smith

Active Member
Joined
Feb 28, 2003
Messages
324
Is there a way to make the above perform at a global level (personal workbook macro) instead of being contained to just one workbook?
 
Upvote 0

Colin Legg

MrExcel MVP
Joined
Feb 28, 2008
Messages
3,497
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Sure, you would have to trap events at the application level rather than at the workbook or worksheet level.

Something like this *not properly tested*:

Add a class module called cAppEvents:
Code:
Option Explicit
 
Private WithEvents pApp As Excel.Application
Private pPreviousSheet As Object
 
Public Property Set AppEvent(Value As Excel.Application)
    Set pApp = Value
End Property
 
Private Sub pApp_SheetActivate(ByVal Sh As Object)
    If Not pPreviousSheet Is Nothing Then MsgBox pPreviousSheet.Parent.Name & "!" & pPreviousSheet.Name & " deactivated"
    MsgBox Sh.Parent.Name & "!" & Sh.Name & " activated"
End Sub
Private Sub pApp_SheetDeactivate(ByVal Sh As Object)
    Set pPreviousSheet = Sh
End Sub
 
Private Sub pApp_WorkbookActivate(ByVal Wb As Workbook)
    If Not pPreviousSheet Is Nothing Then MsgBox pPreviousSheet.Parent.Name & "!" & pPreviousSheet.Name & " deactivated"
    MsgBox Wb.Name & "!" & Wb.ActiveSheet.Name & " activated"
End Sub
Private Sub pApp_WorkbookDeactivate(ByVal Wb As Workbook)
    Set pPreviousSheet = Wb.ActiveSheet
End Sub

And then perhaps some code in the ThisWorkbook class module to get it going:
Code:
Option Explicit
 
Private xlApp As cAppEvents
 
Private Sub Workbook_Open()
    Set xlApp = New cAppEvents
    Set xlApp.AppEvent = Excel.Application
End Sub

Hope that helps...
 
Upvote 0

Forum statistics

Threads
1,190,959
Messages
5,983,863
Members
439,867
Latest member
Shadrack

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