Report of Unprotected and protected tabs in work?

LenPL

New Member
Joined
Aug 1, 2013
Messages
17
Hi,

I am looking for a quick option to list the protection status of all the tabs in a workbook.

I already have the following Macro which lists and hyperlinks all the tabs in workbook

Code:
Sub Index()
Dim wbBook As Workbook
Dim wsActive As Worksheet
Dim wsSheet As Worksheet
Dim lnRow As Long
Dim lnPages As Long
Dim lnCount As Long
Set wbBook = ActiveWorkbook
With Application
    .DisplayAlerts = False
    .ScreenUpdating = False
End With
'If the TOC sheet already exist delete it and add a new
'worksheet.
On Error Resume Next
With wbBook
    .Worksheets("TOC").Delete
    .Worksheets.Add Before:=.Worksheets(1)
End With
On Error GoTo 0
Set wsActive = wbBook.ActiveSheet
With wsActive
    .Name = "TOC"
    With .Range("A1:B1")
        .Value = VBA.Array("Table of Contents", "Sheet # - # of Pages")
        .Font.Bold = True
    End With
End With
lnRow = 2
lnCount = 1
'Iterate through the worksheets in the workbook and create
'sheetnames, add hyperlink and count & write the running number
'of pages to be printed for each sheet on the TOC sheet.
For Each wsSheet In wbBook.Worksheets
    If wsSheet.Name <> wsActive.Name Then
        wsSheet.Activate
        With wsActive
            .Hyperlinks.Add .Cells(lnRow, 1), "", _
            SubAddress:="'" & wsSheet.Name & "'!A1", _
            TextToDisplay:=wsSheet.Name
            lnPages = wsSheet.PageSetup.Pages().Count
            .Cells(lnRow, 2).Value = "'" & lnCount & "-" & lnPages
        End With
        lnRow = lnRow + 1
        lnCount = lnCount + 1
    End If
Next wsSheet
wsActive.Activate
wsActive.Columns("A:B").EntireColumn.AutoFit
With Application
    .DisplayAlerts = True
    .ScreenUpdating = True
End With
End Sub

Thanks in advance
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Maybe this could get you started.
Code:
Sub GetProtectionStatus()
    If ActiveSheet.ProtectContents = True Then
       MsgBox "Protected"
    Else
       MsgBox "Not protected"
    End If
End Sub
 
Upvote 0
Maybe this could get you started.
Code:
Sub GetProtectionStatus()
    If ActiveSheet.ProtectContents = True Then
       MsgBox "Protected"
    Else
       MsgBox "Not protected"
    End If
End Sub

Thanks Mumps, I was actually after something along the lines of.

[TABLE="width: 167"]
<TBODY>[TR]
[TD]Sheet1</SPAN>[/TD]
[TD]Protected</SPAN>[/TD]
[/TR]
[TR]
[TD]Sheet2</SPAN>[/TD]
[TD]Not protected</SPAN>[/TD]
[/TR]
[TR]
[TD]Sheet3</SPAN>[/TD]
[TD]Not protected</SPAN>[/TD]
[/TR]
</TBODY><COLGROUP><COL><COL></COLGROUP>[/TABLE]
 
Upvote 0
Do you want the protected status list copied to a particular location or do you just want a message box popping up giving you the status as you loop through each sheet? Also keep in mind that if the sheet is protected, the code will not run on it. An error message will be generated.
 
Last edited:
Upvote 0
You can place this code at the end of your current code. Create a new worksheet and name it "Status". This will store the worksheet status and then run your macro.
Code:
Dim ws As Worksheet
    For Each ws In Sheets
        If ws.ProtectContents = True Then
           Sheets("Status").Cells(Rows.Count, "A").End(xlUp).Offset(1, 0) = ws.Name & " Protected"
        Else
           Sheets("Status").Cells(Rows.Count, "A").End(xlUp).Offset(1, 0) = ws.Name & " Unprotected"
        End If
    Next ws
 
Upvote 0
Finally Cracked it. Thanks Mumps

Code:
Sub Index()
Dim wbBook As Workbook
Dim wsActive As Worksheet
Dim wsSheet As Worksheet
Dim lnRow As Long
Dim lnPages As Long
Dim lnCount As Long
Set wbBook = ActiveWorkbook
With Application
    .DisplayAlerts = False
    .ScreenUpdating = False
End With
'If the TOC sheet already exist delete it and add a new
'worksheet.
On Error Resume Next
With wbBook
    .Worksheets("TOC").Delete
    .Worksheets.Add Before:=.Worksheets(1)
End With
On Error GoTo 0
Set wsActive = wbBook.ActiveSheet
With wsActive
    .Name = "TOC"
    With .Range("A1:D1")
        .Value = VBA.Array("Table of Contents", "Sheet #", "# of Pages", "Protection")
        .Font.Bold = True
    End With
End With
lnRow = 2
lnCount = 1
'Iterate through the worksheets in the workbook and create
'sheetnames, add hyperlink and count & write the running number
'of pages to be printed for each sheet on the TOC sheet.
For Each wsSheet In wbBook.Worksheets
    If wsSheet.Name <> wsActive.Name Then
        wsSheet.Activate
        With wsActive
            .Hyperlinks.Add .Cells(lnRow, 1), "", _
            SubAddress:="'" & wsSheet.Name & "'!A1", _
            TextToDisplay:=wsSheet.Name
            lnPages = wsSheet.PageSetup.Pages().Count
            .Cells(lnRow, 2).Value = "'" & lnCount
            .Cells(lnRow, 3).Value = lnPages
        If wsSheet.ProtectContents = True Then
           .Cells(lnRow, 4).End(xlUp).Offset(1, 0) = "Protected"
        Else
           .Cells(lnRow, 4).End(xlUp).Offset(1, 0) = "Unprotected"
        End If
        End With
        lnRow = lnRow + 1
        lnCount = lnCount + 1
    End If
Next wsSheet
wsActive.Activate
wsActive.Columns("A:D").EntireColumn.AutoFit
With Application
    .DisplayAlerts = True
    .ScreenUpdating = True
End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

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