VBA Hide text boxes based on Cell value, Code?

Tank997

Board Regular
Joined
Feb 12, 2005
Messages
62
Office Version
  1. 365
Platform
  1. Windows
I have the code below on a worksheet to modify a form based if it's a Purchase order or not. It works but it seems like it could be much shorter. I tried several different ways to write it but I can't get it to work any other way. I was hoping someone could tell me if there is a better way to do this or if this is the correct way.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
' If cell E5 = "Purchase Order" remove sales tax % from E33 and Hide Text Boxes 1 and 8
    
    If Target.Address = Range("E5").Address Then
        If Target = "Purchase Order" Then
            Range("E33").Value = 0
            With ActiveSheet.Shapes("Text Box 1")
                If ActiveSheet.Range("E5") = "Purchase Order" Then
                 .Visible = False
                End If
            End With
            With ActiveSheet.Shapes("Text Box 8")
                If ActiveSheet.Range("E5") = "Purchase Order" Then
                  .Visible = False
                 End If
            End With
            Else
                Range("E33").Value = 0.06
            With ActiveSheet.Shapes("Text Box 8")
                If ActiveSheet.Range("E5") <> "Purchase Order" Then
                  .Visible = True
                End If
            End With
            With ActiveSheet.Shapes("Text Box 1")
                If ActiveSheet.Range("E5") <> "Purchase Order" Then
                 .Visible = True
                End If
            End With
         End If
    End If
End Sub

Thanks for any help
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
I haven't tested it, but maybe...

Code:
[FONT=Courier New][COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] Worksheet_Change([COLOR=darkblue]ByVal[/COLOR] Target [COLOR=darkblue]As[/COLOR] Range)
[COLOR=green]' If cell E5 = "Purchase Order" remove sales tax % from E33 and Hide Text Boxes 1 and 8[/COLOR]
    
    [COLOR=darkblue]If[/COLOR] Target.Address = Range("E5").Address [COLOR=darkblue]Then[/COLOR]
        [COLOR=darkblue]If[/COLOR] Target.Value = "Purchase Order" [COLOR=darkblue]Then[/COLOR]
            Range("E33").Value = 0
            ActiveSheet.Shapes.Range(Array("Text Box 1", "Text Box 8")).Visible = [COLOR=darkblue]False[/COLOR]
        [COLOR=darkblue]Else[/COLOR]
            Range("E33").Value = 0.06
            ActiveSheet.Shapes.Range(Array("Text Box 1", "Text Box 8")).Visible = [COLOR=darkblue]True[/COLOR]
         [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
    
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]
[/FONT]
 
Upvote 0
Perfect! I tried something very similar and it would hide the text boxes but it wouldn't unhide them, not sure why.

Thanks Domenic!
 
Upvote 0
You're very welcome! Glad I could help!

Cheers!
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,177
Members
448,554
Latest member
Gleisner2

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