VBA code checks a condition, stops macro if FALSE, etc.

lojanica

New Member
Joined
Feb 22, 2024
Messages
18
Office Version
  1. 365
Platform
  1. Windows
Hi All,

This is my current code to activate sheet based on the value in B6 than perform filtering and sorting.

Private Sub Workbook_Open()

Dim mainwb As Workbook

Set mainwb = ActiveWorkbook

mainwb.Sheets("AMSI-R-102 Job Request Register").Activate

mainwb.Sheets(Range("B6").Value).Activate

mainwb.Sheets(Range("B6").Value).Range("A8").Select

If (ActiveSheet.AutoFilterMode And ActiveSheet.FilterMode) Or ActiveSheet.FilterMode Then

ActiveSheet.ShowAllData

End If

Range("A6:I6").AutoFilter field:=8, Criteria1:=Range("B6")

Range("A6:I6").AutoFilter field:=7, Criteria1:="In progress"

lastrow = Cells(Rows.Count, 2).End(xlUp).Row

Range("A8:I" & lastrow).Sort key1:=Range("D8:D" & lastrow), _

order1:=xlAscending, Header:=xlNo


End Sub



The cell B6 picks up username and opens tab with matching tab name than performs remaining code.

Currently if the username opening document does not have existing tab code spits out error message, how do I make code to check if “mainwb.Sheets(Range("B6").Value).Activate” is true otherwise stop macro and keep mainwb.Sheets("AMSI-R-102 Job Request Register").Activate?
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Try this on a copy.

VBA Code:
Private Sub Workbook_Open()

    Dim mainwb As Workbook
    Dim usernameSheetName As String
    Dim targetSheet As Worksheet
    
    Set mainwb = ActiveWorkbook
    usernameSheetName = mainwb.Sheets("AMSI-R-102 Job Request Register").Range("B6").Value
    
    On Error Resume Next
    Set targetSheet = mainwb.Sheets(usernameSheetName)
    On Error GoTo 0
    
    If Not targetSheet Is Nothing Then
        targetSheet.Activate
    Else
        mainwb.Sheets("AMSI-R-102 Job Request Register").Activate
        Exit Sub
    End If

    If (ActiveSheet.AutoFilterMode And ActiveSheet.FilterMode) Or ActiveSheet.FilterMode Then
        ActiveSheet.ShowAllData
    End If

    Range("A6:I6").AutoFilter Field:=8, Criteria1:=Range("B6")
    Range("A6:I6").AutoFilter Field:=7, Criteria1:="In progress"
    
    lastrow = Cells(Rows.Count, 2).End(xlUp).Row
    Range("A8:I" & lastrow).Sort Key1:=Range("D8:D" & lastrow), Order1:=xlAscending, Header:=xlNo

End Sub
 
Upvote 0
Solution
Try this on a copy.

VBA Code:
Private Sub Workbook_Open()

    Dim mainwb As Workbook
    Dim usernameSheetName As String
    Dim targetSheet As Worksheet
   
    Set mainwb = ActiveWorkbook
    usernameSheetName = mainwb.Sheets("AMSI-R-102 Job Request Register").Range("B6").Value
   
    On Error Resume Next
    Set targetSheet = mainwb.Sheets(usernameSheetName)
    On Error GoTo 0
   
    If Not targetSheet Is Nothing Then
        targetSheet.Activate
    Else
        mainwb.Sheets("AMSI-R-102 Job Request Register").Activate
        Exit Sub
    End If

    If (ActiveSheet.AutoFilterMode And ActiveSheet.FilterMode) Or ActiveSheet.FilterMode Then
        ActiveSheet.ShowAllData
    End If

    Range("A6:I6").AutoFilter Field:=8, Criteria1:=Range("B6")
    Range("A6:I6").AutoFilter Field:=7, Criteria1:="In progress"
   
    lastrow = Cells(Rows.Count, 2).End(xlUp).Row
    Range("A8:I" & lastrow).Sort Key1:=Range("D8:D" & lastrow), Order1:=xlAscending, Header:=xlNo

End Sub
Works perfectly :) Thank you!!
 
Upvote 0
@lojanica
For the future, when posting vba code in the forum, please use the available code tags. It makes your code much easier to read/debug & copy. My signature block below has more details.
 
Upvote 1

Forum statistics

Threads
1,215,071
Messages
6,122,964
Members
449,094
Latest member
Anshu121

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
Back
Top