MarkOW

New Member
Joined
Jun 26, 2018
Messages
27
Hi I have VBA code that I have written.......

It works but looks untidy.

Can someone offer advice on how to tidy it up with a loop so I can extend the ranges that are compared? (Extend to B3:30 & C3:C30)

Code:
Private Sub CommandButton1_Click()
'Security Pin
            


    If Worksheets("Datasheet").Range("C3").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B3").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C4").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B4").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C5").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B5").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


  
    ElseIf Worksheets("Datasheet").Range("C6").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B6").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C7").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B7").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C8").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B8").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    ElseIf Worksheets("Datasheet").Range("C9").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B9").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C10").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B10").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C11").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B11").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C12").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B12").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass
 
    
    ElseIf Worksheets("Datasheet").Range("C13").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B13").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass


    
    ElseIf Worksheets("Datasheet").Range("C14").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B14").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass
    
    ElseIf Worksheets("Datasheet").Range("C15").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B15").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass
    Else
    
    
     MsgBox Prompt:="Incorrect PIN", Buttons:=vbCritical
     
     Me.PIN2.Value = ""


     Unload Me
     GoTo ReTry
     
ByPass:


     End If
     
    
    Call Signnow


ReTry:


    End Sub

thanks again

Mark

Office 365 Windows 10
 
Last edited:

Some videos you may like

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"

mole999

Moderator
Joined
Oct 23, 2004
Messages
10,524
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
like this maybe
Code:
Private Sub CommandButton1_Click()
'Security Pin
  Dim n As interger

For n = 3 To 15 Step 1

    If Worksheets("Datasheet").Range("C" & n).Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B" & n).Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass

    Else
    
    
     MsgBox Prompt:="Incorrect PIN", Buttons:=vbCritical
     
     Me.PIN2.Value = ""


     Unload Me
     GoTo ReTry
     
ByPass:


     End If
     
    
    Call Signnow


ReTry:


    End Sub
 

MarkOW

New Member
Joined
Jun 26, 2018
Messages
27
Hi, and thanks.

I am getting the error for without next. Where does the next go?

Thanks again
 

mole999

Moderator
Joined
Oct 23, 2004
Messages
10,524
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
Code:
Private Sub CommandButton1_Click()
'Security Pin
  Dim n As interger

For n = 3 To 15 Step 1

    If Worksheets("Datasheet").Range("C" & n).Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B" & n).Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass
    
[COLOR=#ff0000]    Next n
[/COLOR]
    Else
    
    
     MsgBox Prompt:="Incorrect PIN", Buttons:=vbCritical
     
     Me.PIN2.Value = ""


     Unload Me
     GoTo ReTry
     
ByPass:


     End If
     
    
    Call Signnow


ReTry:


    End Sub
thats what happens when you can't test it :), item in red i think
 

MarkOW

New Member
Joined
Jun 26, 2018
Messages
27

ADVERTISEMENT

Hi again ,

I tried that first but end up with error

Next without For.

Mark
 

mole999

Moderator
Joined
Oct 23, 2004
Messages
10,524
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
a different tweak
Code:
Private Sub CommandButton1_Click()
'Security Pin
  Dim n As Integer

    If Worksheets("Datasheet").Range("C3").Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B3").Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass
    
For n = 4 To 15 Step 1
     
     ElseIf Worksheets("Datasheet").Range("C" & n).Value = CStr(Me.PIN2.Text) And Worksheets("Datasheet").Range("B" & n).Value = CStr(Me.ComboBox1.Value) Then
    GoTo ByPass
    
    Next n

    Else
    
     MsgBox Prompt:="Incorrect PIN", Buttons:=vbCritical
     
     Me.PIN2.Value = ""

     Unload Me
     GoTo ReTry
ByPass:
     End If
    Call Signnow
ReTry:
    End Sub
 

MarkOW

New Member
Joined
Jun 26, 2018
Messages
27

ADVERTISEMENT

Hi Again

Another error I'm afraid.

Else without If
 

mole999

Moderator
Joined
Oct 23, 2004
Messages
10,524
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
currently out of ideas then, it will be something on that theme
 

MarkOW

New Member
Joined
Jun 26, 2018
Messages
27
Thanks for your help.

I have tried a lot of variations but hit a wall!

Mark
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
52,755
Office Version
  1. 365
Platform
  1. Windows
How about
Code:
Private Sub CommandButton1_Click()
'Security Pin
   Dim i As Long
   Dim Flg As Boolean
   
   With Worksheets("Datasheet")
      For i = 3 To 15
         If .Range("C" & i).Value = CStr(Me.PIN2.Text) And .Range("B" & i).Value = CStr(Me.ComboBox1.Value) Then
            Flg = True
            Exit For
         End If
      Next i
   End With
   If Flg = False Then
      MsgBox prompt:="Incorrect PIN", Buttons:=vbCritical
      Me.PIN2.Value = ""
      Unload Me
      Exit Sub
   End If
      
   Call Signnow
End Sub
 

Watch MrExcel Video

Forum statistics

Threads
1,122,230
Messages
5,594,949
Members
413,953
Latest member
Arthur1471

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
Top