Speed up VBA Code (Hide Blank cells based on specific cell)

CamC

New Member
Joined
Jun 24, 2022
Messages
5
Office Version
  1. 2021
  2. 2019
  3. 2016
  4. 2013
Platform
  1. Windows
Hi there,

I have the following code that is working, but it is taking around 1 min to run. Is there anything I can do to improve the vba Speed?

What I am trying to do is automatically hiding blank rows (from B68 to B362) after Pasting in cell B27. This macro run for Sheet2 only (There is another different macro for Sheet1)

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    ' Show any hidden rows if this macro has been used
    Range("68:362").EntireRow.Hidden = False
    'Automate run macro if Past used in cell B27
        If Intersect(Target, Range("B27")) Is Nothing Then Exit Sub
        Application.ScreenUpdating = False
    'Hide rows if blank
        For Each cell In Range("B68:B362")
            If cell.Value2 = "" Then cell.EntireRow.Hidden = True
        Next cell
    Application.ScreenUpdating = True
End Sub

Much appreciated any help
 
Last edited by a moderator:

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)
If B27:B362 contains no formulas :
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

'Automate run macro if B27 changed
If Intersect(Target, Range("B27")) Is Nothing Then Exit Sub

With Application
    .Calculation = xlCalculationManual
    .ScreenUpdating = False
    .EnableEvents = False

' Hide all rows
Range("68:362").EntireRow.Hidden = True
'Unhide rows if not blank
Range("B68:B362").SpecialCells(xlCellTypeConstants).EntireRow.Hidden = False
    
    .Calculation = xlCalculationAutomatic
    .ScreenUpdating = True
    .EnableEvents = True
End With

End Sub
If B68:B362 contains formulas, post again.
 
Upvote 1
Solution
@CamC
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. I have added the tags for you this time. 😊
 
Upvote 0
If B27:B362 contains no formulas :
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

'Automate run macro if B27 changed
If Intersect(Target, Range("B27")) Is Nothing Then Exit Sub

With Application
    .Calculation = xlCalculationManual
    .ScreenUpdating = False
    .EnableEvents = False

' Hide all rows
Range("68:362").EntireRow.Hidden = True
'Unhide rows if not blank
Range("B68:B362").SpecialCells(xlCellTypeConstants).EntireRow.Hidden = False
   
    .Calculation = xlCalculationAutomatic
    .ScreenUpdating = True
    .EnableEvents = True
End With

End Sub
If B68:B362 contains formulas, post again.
Its worked perfect. Thank you so much footoo
 
Upvote 0
@CamC
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. I have added the tags for you this time. 😊
Tks so much. Good to know
 
Upvote 0

Forum statistics

Threads
1,224,819
Messages
6,181,153
Members
453,021
Latest member
Justyna P

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