Failed macro because sheet protected

willisbr

New Member
Joined
Mar 2, 2006
Messages
29
I have a protected sheet that I have a toggle button in. The toggle hides and unhides columns. The code failes and the toggle wont work if the sheet is protected. Is there a way to build the protect/unprotect within the toggle also? I've tried a few things but so far no good.
The only reason I have the sheet protected is to prevent a function from being overwritten or deleted...so if anything, I thought I can get the toggle to unprotect the sheet...do what it needs to do...and then reprotect again.

I'm using Excel 97

here is the current toggle code:

Private Sub CommandButton1_Click()

a = InputBox("Enter password:", "Security")
If a <> "password" Then
MsgBox "The password you entered is incorrect."
End
End If
With CommandButton1
If CommandButton1.Caption = "Hide Raw Data" Then

Range("C:D,F:G,I:J,M:P,R:S,U:V,X:Y,AA:AE,AG:AH").Select
Selection.EntireColumn.Hidden = True

CommandButton1.Caption = "Show Raw Data"
Else
Range("C:D,F:G,I:J,M:P,R:S,U:V,X:Y,AA:AE,AG:AH").Select
Selection.EntireColumn.Hidden = False
Range("C5").Select
CommandButton1.Caption = "Hide Raw Data"
End If
End With
End Sub
 
Hello willisbr,
This code can be found on dk's web site for that:
(Goes into a standard module.)
Code:
Option Explicit
'PROCEDURE TO MAKE INPUTBOXES SHOW PASSWORD CHARACTERS
'API functions to be used
Private Declare Function CallNextHookEx Lib "user32" (ByVal hHook As Long, _
ByVal ncode As Long, ByVal wParam As Long, lParam As Any) As Long

Private Declare Function GetModuleHandle Lib "kernel32" Alias "GetModuleHandleA" (ByVal lpModuleName As String) As Long

Private Declare Function SetWindowsHookEx Lib "user32" Alias "SetWindowsHookExA" _
(ByVal idHook As Long, ByVal lpfn As Long, ByVal hmod As Long, _
ByVal dwThreadId As Long) As Long

Private Declare Function UnhookWindowsHookEx Lib "user32" (ByVal hHook As Long) As Long

Private Declare Function SendDlgItemMessage Lib "user32" Alias "SendDlgItemMessageA" _
(ByVal hDlg As Long, ByVal nIDDlgItem As Long, ByVal wMsg As Long, _
ByVal wParam As Long, ByVal lParam As Long) As Long

Private Declare Function GetClassName Lib "user32" Alias "GetClassNameA" (ByVal hwnd As Long, _
ByVal lpClassName As String, _
ByVal nMaxCount As Long) As Long

Private Declare Function GetCurrentThreadId Lib "kernel32" () As Long

'Constants to be used in our API functions
Private Const EM_SETPASSWORDCHAR = &HCC
Private Const WH_CBT = 5
Private Const HCBT_ACTIVATE = 5
Private Const HC_ACTION = 0

Private hHook As Long

Public Function NewProc(ByVal lngCode As Long, ByVal wParam As Long, ByVal lParam As Long) As Long
Dim RetVal
Dim strClassName As String, lngBuffer As Long

If lngCode < HC_ACTION Then
  NewProc = CallNextHookEx(hHook, lngCode, wParam, lParam)
  Exit Function
End If

strClassName = String$(256, " ")
lngBuffer = 255

If lngCode = HCBT_ACTIVATE Then 'A window has been activated
  RetVal = GetClassName(wParam, strClassName, lngBuffer)
  If Left$(strClassName, RetVal) = "#32770" Then 'Class name of the Inputbox
    'This changes the edit control so that it displays the password character *.
    'You can change the Asc("*") as you please.
    SendDlgItemMessage wParam, &H1324, EM_SETPASSWORDCHAR, Asc("*"), &H0
  End If
End If

'This line will ensure that any other hooks that may be in place are
'called correctly.
CallNextHookEx hHook, lngCode, wParam, lParam

End Function

Public Function InputBoxDK(Prompt, Optional Title, Optional Default, Optional XPos, _
Optional YPos, Optional HelpFile, Optional Context) As String
Dim lngModHwnd As Long, lngThreadID As Long
lngThreadID = GetCurrentThreadId
lngModHwnd = GetModuleHandle(vbNullString)
hHook = SetWindowsHookEx(WH_CBT, AddressOf NewProc, lngModHwnd, lngThreadID)
InputBoxDK = InputBox(Prompt, Title, Default, XPos, YPos, HelpFile, Context)
UnhookWindowsHookEx hHook
End Function

Then you call the inputbox like so:
(Also goes into a standard module.)
Code:
Sub InputBoxDK_Demo()
  xyz = InputBoxDK("Inputbox Prompt", "InputBox Title")
  If xyz = "Your Password" Then
    MsgBox "Correct password"
  Else
    MsgBox "Incorrect password"
  End If
End Sub


dk's web site:
http://www.danielklann.com/
 
Upvote 0

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney

Forum statistics

Threads
1,216,014
Messages
6,128,287
Members
449,436
Latest member
blaineSpartan

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