Results 1 to 7 of 7
  1. #1
    Bronze Lounger
    Join Date
    Feb 2008
    Posts
    1,421
    Thanks
    124
    Thanked 5 Times in 5 Posts

    Hide Rows Where data is zero

    I have data in Sheet1. I would like a macro to hide the rows where the value in ColD is zero

  2. #2
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,436
    Thanks
    372
    Thanked 1,457 Times in 1,326 Posts
    Howard,

    This should do the trick:

    Code:
    Option Explicit
    
    Sub HideZeroRows()
    
       Dim lLastRow  As Long
       Dim lRowCnt   As Long
    
       lLastRow = Cells(Rows.Count, 4).End(xlUp).Row()
    
       For lRowCnt = lLastRow To 2 Step -1
          If Cells(lRowCnt, 4).Value = 0 Then _
            Rows(lRowCnt).EntireRow.Hidden = True
       Next lRowCnt
       
    End Sub  'HideZeroRows
    
    Sub UnHideZeroRows()
    
       Dim lLastRow  As Long
       Dim lRowCnt   As Long
    
       lLastRow = Cells(Rows.Count, 4).End(xlUp).Row()
    
       For lRowCnt = lLastRow To 2 Step -1
          If Cells(lRowCnt, 4).Value = 0 Then _
            Rows(lRowCnt).EntireRow.Hidden = False
       Next lRowCnt
       
    End Sub  'UnHideZeroRows
    Note: The code finds the last row with data in Col D because you need to hide going up so you don't miss rows. It also assumes there is a title on the row change the 2 n the Cells line to 1 if not. HTH
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  3. The Following User Says Thank You to RetiredGeek For This Useful Post:

    HowardC (2013-08-27)

  4. #3
    Gold Lounger Maudibe's Avatar
    Join Date
    Aug 2010
    Location
    Pa, USA
    Posts
    2,638
    Thanks
    115
    Thanked 650 Times in 592 Posts
    Another way to achieve the same thing:

    Code:
    Public Sub Hiderows()
    Lastrow = Cells(Rows.Count, 4).End(xlUp).Row
    For Each cell In Range(Cells(1, 4), Cells(Lastrow, 4))
        If cell.Value = 0 Then cell.EntireRow.Hidden = True
    Next cell
    End Sub
    
    Public Sub Unhiderows()
    Lastrow = Cells(Rows.Count, 4).End(xlUp).Row
    For Each cell In Range(Cells(1, 4), Cells(Lastrow, 4))
        If cell.Value = 0 Then cell.EntireRow.Hidden = False
    Next cell
    End Sub
    Maud

  5. The Following 2 Users Say Thank You to Maudibe For This Useful Post:

    HowardC (2013-08-27),RetiredGeek (2013-08-27)

  6. #4
    Bronze Lounger
    Join Date
    Feb 2008
    Posts
    1,421
    Thanks
    124
    Thanked 5 Times in 5 Posts
    Hi RG & Maudibe

    Thanks for the help, much appreciated

  7. #5
    WS Lounge VIP
    Join Date
    Mar 2002
    Location
    Newcazzle, UK
    Posts
    2,829
    Thanks
    136
    Thanked 482 Times in 459 Posts
    Hi All

    Both RG's solution and Maudibe's solution will hide rows where the value in ColD is empty.
    This is generally OK, since a blank empty cell will be treated as zero.

    Both solutions use For..Next loops.
    For faster performance (particulary for very very large numbers of data rows), it is better to avoid loops in vba whenever possible.

    So, a shorter, faster, vba solution that doesn't rely on loops, could be:

    Code:
    Sub UnhideRowsZeddy()
    
    [d1].CurrentRegion.EntireRow.Hidden = False
    
    End Sub
    '*****************************************************************
    
    Sub hideRowsZeddy()
        
    [D:D].Replace What:="0", Replacement:="", LookAt:=xlWhole
    [D:D].SpecialCells(xlCellTypeBlanks).EntireRow.Hidden = True
    
    End Sub
    I have attached a sample file that shows all three proposed solutions.
    Note that with the particular sample data provided, they do not give the same results.
    That might be important in some circumstances.

    zeddy
    Attached Files Attached Files

  8. #6
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,436
    Thanks
    372
    Thanked 1,457 Times in 1,326 Posts
    Zeddy,

    Nice trick, however it doesn't work if column D contains formulas!
    ZeddyHide.JPG
    Whereas both Maud's and mine do.
    RGCode.JPG
    Just goes to show you how hard it is to write code with out all the specs!

    However, the UnHide code is sheer Genius and works Great!
    Last edited by RetiredGeek; 2013-08-28 at 11:58.
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  9. #7
    WS Lounge VIP
    Join Date
    Mar 2002
    Location
    Newcazzle, UK
    Posts
    2,829
    Thanks
    136
    Thanked 482 Times in 459 Posts
    Hi RG

    ..you are sooooo right!

    My main point was to highlight the potential discrepancy of using
    Lastrow = Cells(Rows.Count, 4).End(xlUp).Row
    ..as it could miss out some rows, as per my sample file.

    OK, my new hide rows would be:
    Code:
    Sub hideRows()
    
    Application.ScreenUpdating = False
    zLastRow = [d1].CurrentRegion.Rows.Count
    For Each cell In Range(Cells(1, 4), Cells(zLastRow, 4))
    cell.EntireRow.Hidden = (cell.Value = 0)
    Next
    
    End Sub
    Top marks for the point about formulas returning zero value.

    zeddy

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •