VBA code that find next number

Jagat Pavasia

Active Member
Joined
Mar 9, 2015
Messages
404
Office Version
  1. 2021
Platform
  1. Windows
Capture.JPG


Dear Sir,

I have Excel sheet as shown in Image.
My raw "G3:G1000" has space for serial number.

I want that if I enter any empty space in G3 to G1000 than it see last number and give me next number by entering "**" in G3:G1000.

For Example (As Above Image):

I enter "**" in G5 than result should be "6" in G5, and after that if I enter in G12 than result shoub be next number "7".

please help with VBA code
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
The following enters the next number when anything is entered in a cell in column G
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Count > 1 Then Exit Sub
Application.EnableEvents = False
If Not Intersect([G:G], Target) Is Nothing Then _
    Target = WorksheetFunction.Max([G:G]) + 1
Application.EnableEvents = True
End Sub

The following enters the next number when ** is entered
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Count > 1 Then Exit Sub
Application.EnableEvents = False
If Not Intersect([G:G], Target) Is Nothing Then
    If Target = "**" Then Target = WorksheetFunction.Max([G:G]) + 1
End If
Application.EnableEvents = True
End Sub
 
Upvote 0
yes sir....
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Count > 1 Then Exit Sub
Application.EnableEvents = False
If Not Intersect([G:G], Target) Is Nothing Then
    If Target = "**" Then Target = WorksheetFunction.Max([G:G]) + 1
End If
Application.EnableEvents = True
End Sub


this code is working me, but I have already another VBA code in my sheet.
I tried to merge VBA code, but I failed.
did you help me to merge it ?
my sheet VBA is Below :

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim rng As Range

    If Target.CountLarge > 1 Then Exit Sub

    Application.EnableEvents = False

    Me.Unprotect

    Set rng = Me.Range("B:B,L:L")

    If Not Intersect(Target, rng) Is Nothing Then
        If Target.Value = "**" Then
            Target.Value = Date
            Target.NumberFormat = "DD/MM/YYYY"
        End If
    End If

    If Not Intersect(Target, Me.Range("E1")) Is Nothing Then
        If Target.Value = "" Then
            Me.Range("A3:U3").AutoFilter Field:=Target.Column
        Else
            Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
                                         Operator:=xlFilterValues, _
                                         Criteria1:="*" & CStr(Target.Value) & "*"
        End If
    ElseIf Not Intersect(Target, Me.Range("A1:U1")) Is Nothing Then
        If Target.Value = "" Then
            Me.Range("A3:U3").AutoFilter Field:=Target.Column
        Else
            Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
                                         Operator:=xlFilterValues, _
                                         Criteria1:=CStr(Target.Value)
        End If
    End If

    Me.Protect DrawingObjects:=False, Contents:=True, _
               Scenarios:=False, AllowFormattingCells:=True, _
               AllowFiltering:=True

    Application.EnableEvents = True
End Sub
 
Upvote 0
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.CountLarge > 1 Then Exit Sub
Application.EnableEvents = False
Me.Unprotect
If Not Intersect(Target, [B:B,L:L]) Is Nothing Then
    If Target.Value = "**" Then
        Target.Value = Date
        Target.NumberFormat = "DD/MM/YYYY"
    End If
ElseIf Not Intersect(Target, [E1]) Is Nothing Then
    If Target.Value = "" Then
        Me.Range("A3:U3").AutoFilter Field:=Target.Column
    Else
        Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
            Operator:=xlFilterValues, _
            Criteria1:="*" & CStr(Target.Value) & "*"
    End If
ElseIf Not Intersect(Target, [A1:V1]) Is Nothing Then
    If Target.Value = "" Then
        Me.Range("A3:U3").AutoFilter Field:=Target.Column
    Else
        Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
            Operator:=xlFilterValues, _
            Criteria1:=CStr(Target.Value)
    End If
ElseIf Not Intersect([G:G], Target) Is Nothing Then
    If Target = "**" Then Target = WorksheetFunction.Max([G:G]) + 1
End If
Me.Protect DrawingObjects:=False, Contents:=True, _
           Scenarios:=False, AllowFormattingCells:=True, _
           AllowFiltering:=True
Application.EnableEvents = True
End Sub
 
Upvote 0
Solution
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.CountLarge > 1 Then Exit Sub
Application.EnableEvents = False
Me.Unprotect
If Not Intersect(Target, [B:B,L:L]) Is Nothing Then
    If Target.Value = "**" Then
        Target.Value = Date
        Target.NumberFormat = "DD/MM/YYYY"
    End If
ElseIf Not Intersect(Target, [E1]) Is Nothing Then
    If Target.Value = "" Then
        Me.Range("A3:U3").AutoFilter Field:=Target.Column
    Else
        Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
            Operator:=xlFilterValues, _
            Criteria1:="*" & CStr(Target.Value) & "*"
    End If
ElseIf Not Intersect(Target, [A1:V1]) Is Nothing Then
    If Target.Value = "" Then
        Me.Range("A3:U3").AutoFilter Field:=Target.Column
    Else
        Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
            Operator:=xlFilterValues, _
            Criteria1:=CStr(Target.Value)
    End If
ElseIf Not Intersect([G:G], Target) Is Nothing Then
    If Target = "**" Then Target = WorksheetFunction.Max([G:G]) + 1
End If
Me.Protect DrawingObjects:=False, Contents:=True, _
           Scenarios:=False, AllowFormattingCells:=True, _
           AllowFiltering:=True
Application.EnableEvents = True
End Sub
thank you very much
 
Upvote 0
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.CountLarge > 1 Then Exit Sub
Application.EnableEvents = False
Me.Unprotect
If Not Intersect(Target, [B:B,L:L]) Is Nothing Then
    If Target.Value = "**" Then
        Target.Value = Date
        Target.NumberFormat = "DD/MM/YYYY"
    End If
ElseIf Not Intersect(Target, [E1]) Is Nothing Then
    If Target.Value = "" Then
        Me.Range("A3:U3").AutoFilter Field:=Target.Column
    Else
        Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
            Operator:=xlFilterValues, _
            Criteria1:="*" & CStr(Target.Value) & "*"
    End If
ElseIf Not Intersect(Target, [A1:V1]) Is Nothing Then
    If Target.Value = "" Then
        Me.Range("A3:U3").AutoFilter Field:=Target.Column
    Else
        Me.Range("A3:U3").AutoFilter Field:=Target.Column, _
            Operator:=xlFilterValues, _
            Criteria1:=CStr(Target.Value)
    End If
ElseIf Not Intersect([G:G], Target) Is Nothing Then
    If Target = "**" Then Target = WorksheetFunction.Max([G:G]) + 1
End If
Me.Protect DrawingObjects:=False, Contents:=True, _
           Scenarios:=False, AllowFormattingCells:=True, _
           AllowFiltering:=True
Application.EnableEvents = True
End Sub
Capture.JPG


DEAR, FOOTOO.....
I have same another sheet which has series of K-1, K-2, K-3...
which VBA code for this sheet ?

footoo....please help me to this sheet also...pls...pls...
 
Upvote 0
If you format the cells like this : "K-"0 then you can use the same code.
 
Upvote 0
You can use VBA but it is much simpler to custom format the cells "K-"0
Why is it not possible for you?
Because I had already manually typed K-1, K-2 .....to.................K-1233.
now, I changed format of all cell, and type "**" in empty cell but it did not working.

so, I told you,,,dear..footoo
 
Upvote 0

Forum statistics

Threads
1,223,162
Messages
6,170,432
Members
452,326
Latest member
johnshaji

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