Consulting

Results 1 to 5 of 5

Thread: Conflict Protect and WS_Calculation

  1. #1
    Mac Moderator VBAX Expert shades's Avatar
    Joined
    May 2004
    Location
    Kansas City, USA
    Posts
    638
    Location

    Conflict Protect and WS_Calculation

    I have updated a template that changes by quarter. The worksheet_Calculate code looks at the data and changes how many rows are visible, depending on whether there is data in the underlying data base. It works great.

    Private Sub Worksheet_Calculate()
    Dim i As Integer
    Application.ScreenUpdating = False
    For i = 10 To 20
    Select Case Cells(i, 2).Value
    Case 0
    Worksheets("QtrCharts").Rows(i & ":20").EntireRow.Hidden = True
    Case Else
    Worksheets("QtrCharts").Rows(i & ":20").EntireRow.Hidden = False
    End Select
    Next i
    Application.ScreenUpdating = True
    End Sub
    However, I send this template to about 80 people throughout the US, and I have always used Worksheet Protection (to prevent accidental changes). Until I added the above code, the protection works fine.

    Sub ProtectAll()
    Dim ws As Worksheet
    Application.ScreenUpdating = False
    For Each ws In ActiveWorkbook.Worksheets
    ws.Protect Password:="password", DrawingObjects:=True, _
    Contents:=True, Scenarios:=True
    Next ws
    ActiveWorkbook.Protect Password:="password", _
    Structure:=True, Windows:=False
    Application.ScreenUpdating = True
    End Sub

    Now that I have both in the workbook, in the WS_Calculate code, this line of code errors ("Unable to set the Hidden property of the Range class"):


    Case Else
    Worksheets("QtrCharts").Rows(i & ":20").EntireRow.Hidden = False
    When I look at the Protection options, it allows inserting and deleting of rows, but not hiding. Is there a way to accomplish this?

    Software: LibreOffice 3.3 on Mac OS X 10.6.5
    (retired Excel 2003 user, 3.28.2008 )
    Humanware: Older than dirt
    --------------------
    old, slow, and confused
    but at least I'm inconsistent!

    Rich

  2. #2
    Site Admin
    Urban Myth
    VBAX Guru
    Joined
    May 2004
    Location
    Oregon, United States
    Posts
    4,940
    Location
    Turn protection off, make the change, then turn protection back on. It's pretty much standard PITA, I mean practice. Also, I'd suggest throwing in an Application.EnableEvents clause with your ScreenUpdating as the Calculate event will trigger other events when hiding/unhiding rows/columns.

  3. #3
    Site Admin
    Jedi Master
    VBAX Guru Jacob Hilderbrand's Avatar
    Joined
    Jun 2004
    Location
    Roseville, CA
    Posts
    3,712
    Location
    Another thing you can use is the UserInterfaceOnly Property. This will protect the worksheet only for the user and macros will be able to run as if the worksheet was not protected.

    This property cannot be permanently set though, so you need to set it on the workbook open event or at the beginning of your macro.

    Dim ws As Worksheet
    For Each ws In Worksheets
    ws.Protect Password:="Password", DrawingObjects:=True, _
    Contents:=True, Scenarios:=True, UserInterfaceOnly:=True
    Next

  4. #4
    Mac Moderator VBAX Expert shades's Avatar
    Joined
    May 2004
    Location
    Kansas City, USA
    Posts
    638
    Location
    Thanks, guys. Jake, that piece, UserInterfaceOnly:=True, was exactly what I needed. Now I am very happy, because the auto-updating of the table (different sizes) has been well-received, and the protection code is the final capstone. Thank you!

    Software: LibreOffice 3.3 on Mac OS X 10.6.5
    (retired Excel 2003 user, 3.28.2008 )
    Humanware: Older than dirt
    --------------------
    old, slow, and confused
    but at least I'm inconsistent!

    Rich

  5. #5
    Site Admin
    Jedi Master
    VBAX Guru Jacob Hilderbrand's Avatar
    Joined
    Jun 2004
    Location
    Roseville, CA
    Posts
    3,712
    Location
    Glad to help.

Posting Permissions

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