Macro works on 3 of 4 worksheets

cm1023

New Member
Joined
Mar 18, 2021
Messages
3
Office Version
  1. 2016
Platform
  1. Windows
First time posting - thanks in advance for your patience.

I have a macro to unhide/hide rows on selected sheets in a workbook based on the entry in ColB. The macro works on 3 of the 4 sheets - it does not run on the 4th 'Sponsored Funds Projection' sheet. If run while on the 4th sheet ('SFP'), it works for all 4. The 'Salary Summary' sheet is the data entry source that feeds the other sheets and I eventually want to create a button to run the macro from there, so it really needs to work from that sheet. The code I have is below (I pieced it together from various sites, including here). . Any insight is appreciated.

VBA Code:
Sub HideUnhideRows()

Dim mySheet As Variant, sheetsToEdit As Variant
   
sheetsToEdit = Array("Salary Summary", "Personnel Detail", "All Funds Projection", "Sponsored Funds Projection")

For Each mySheet In sheetsToEdit
   
    Cells.EntireRow.Hidden = False
   
        BeginRow = 6
        EndRow = 200
        ChkCol = 2

    For RowCnt = BeginRow To EndRow
        If Cells(RowCnt, ChkCol).Value = x Then
            Cells(RowCnt, ChkCol).EntireRow.Hidden = True
            End If
    Next RowCnt
   
    Worksheets(mySheet).Activate
    MsgBox mySheet & " will be edited"
   
Next

End Sub
 
Last edited by a moderator:

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Hi & welcome to MrExcel.
What is the x meant to be on this line
VBA Code:
If Cells(RowCnt, ChkCol).Value = x Then
 
Upvote 0
x is x. The user will enter x in a cell in Col B on the Salary Summary Worksheet if they want that row unhidden (or else leave it blank). This feeds through to the corresponding rows on the other 3 worksheets. The macro is set up to first unhide all rows and then hide all those without an x in ColB.
 
Upvote 0
In that case you code is only working by pure chance, it is not looking to see if the has an x in it, it's looking to see if the cell is blank or 0.
Try
VBA Code:
Sub HideUnhideRows()

Dim mySheet As Variant, sheetsToEdit As Variant
   
sheetsToEdit = Array("Salary Summary", "Personnel Detail", "All Funds Projection", "Sponsored Funds Projection")

For Each mySheet In sheetsToEdit
   
    Sheets(mySheet).Cells.EntireRow.Hidden = False
   
        BeginRow = 6
        EndRow = 200
        ChkCol = 2

    For RowCnt = BeginRow To EndRow
        If Sheets(mySheet).Cells(RowCnt, ChkCol).Value <> "x" Then
            Sheets(mySheet).Cells(RowCnt, ChkCol).EntireRow.Hidden = True
            End If
    Next RowCnt
   
    MsgBox mySheet & " will be edited"
   
Next

End Sub
 
Upvote 0
Solution
Thanks Fluff - your code did the trick. One lesson here is if the code 'sort of' works then it doesn't really work at all!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,164
Messages
6,170,444
Members
452,326
Latest member
johnshaji

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