Problem with Auto Incrementing Text String

WednesdayC

Board Regular
Joined
Nov 7, 2010
Messages
201
Office Version
  1. 2016
Platform
  1. MacOS
Hi All

I am having difficulties with creating a formula to deal with the following:-

I am trying to autoincrement the last character (1, 2 or 3 characters) of a text string.

The problem is the string could be different lengths and needs to autoincrement from whatever the last number is from the cell in the row above.

So if the text string in say Cell A2 is [TABLE="width: 132"]
<colgroup><col style="mso-width-source:userset;mso-width-alt:4827;width:132pt" width="132"> </colgroup><tbody>[TR]
[TD="class: xl73, width: 132"]3/1/2018/XXXX/XXX1
[/TD]
[/TR]
</tbody>[/TABLE]

Cell A2 should be [TABLE="width: 132"]
<colgroup><col style="mso-width-source:userset;mso-width-alt:4827;width:132pt" width="132"> </colgroup><tbody>[TR]
[TD="class: xl73, width: 132"]3/1/2018/XXXX/XXX2
[/TD]
[/TR]
</tbody>[/TABLE]


However if the string in Cell A2 is, say

3/1/2018/XXXX/XXX16

then I require

3/1/2018/XXXX/XXX17

Or

3/1/2018/XXXX/XXX116

Then all the rows downwards should increment by 1, so the result in A2 will be

3/1/2018/XXXX/XXX117

I can't work out how to deal with this, due to the variable length of the strings. Also the Xs are only for the demo, these will really be numbers, but only the last 1, (2 or 3) (if the previous number is 10 or 100 upwards) needs to increment.

Is there a formula that can deal with this please.

Many thanks in advance and I hope I have been clear in my requirements.


Wednesday


<style>table { }td { padding-top: 1px; padding-right: 1px; padding-left: 1px; color: black; font-size: 10pt; font-weight: 400; font-style: normal; text-decoration: none; font-family: Georgia, sans-serif; vertical-align: bottom; border: medium none; white-space: nowrap; }</style><style>table { }td { padding-top: 1px; padding-right: 1px; padding-left: 1px; color: black; font-size: 10pt; font-weight: 400; font-style: normal; text-decoration: none; font-family: Georgia, sans-serif; vertical-align: bottom; border: medium none; white-space: nowrap; }.xl73 { color: windowtext; font-family: Georgia; }</style>
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
Is the format always going to end with a slash, followed by three characters (numbers), followed by the number that you want to increment?
 
Upvote 0
Also, are you open to use creating a function in VBA that we can use on the sheet?
 
Upvote 0
If my assumptions are right, and you can use VBA, here is the Custom function I came up with:
Code:
Function NextNum(entry As String) As String

    Dim lastSlash As Long
    Dim prefix As String
    Dim num As Long
    
'   Make sure there is an entry
    If Len(entry) = 0 Then
        NextNum = ""
        Exit Function
    End If
    
'   Find last slash in entry
    lastSlash = InStrRev(entry, "/")
    
'   Get prefix
    prefix = Left(entry, lastSlash + 3)
    
'   Get number to increment
    num = Right(entry, Len(entry) - (lastSlash + 3)) + 1
    
'   Build next number
    NextNum = prefix & num

End Function
After putting this in VBA (in a General Module in your workbook), you can use it like any other function.

So, if you have your initial value in A2, place this formula in A3 and copy down for all rows:
=NextNum(A2)
 
Last edited:
Upvote 0
Hi Joe

The format will either be slashes or hyphens.
Yes, there will always be 3 characters followed by the number

Yes, I am open to a function, although I would prefer a formula, but if a function is the way to do it, then yes please.

Thanks, in advance, for any help you can give me.

Regards

Wednesday
 
Upvote 0
Hi Joe

It works brilliantly. Thank you so much.

Can it easily be adapted to work with a "/" or a "-" please.

Many thanks

Wednesday
 
Upvote 0
Here is an update of my previous code that will work regardless of whether they use slashes, dashes, or a combination of both:
Code:
Function NextNum(entry As String) As String

    Dim lastSlash As Long
    Dim lastDash As Long
    Dim last As Long
    Dim prefix As String
    Dim num As Long
    
'   Find last slash in entry
    lastSlash = InStrRev(entry, "/")
'   Find last dash in entry
    lastDash = InStrRev(entry, "-")
'   Take maximum of previous two values
    If lastDash > lastSlash Then
        last = lastDash
    Else
        last = lastSlash
    End If
    
'   Make sure there is an entry
    If (Len(entry) = 0) Or (last = 0) Then
        NextNum = ""
        Exit Function
    End If

'   Get prefix
    prefix = Left(entry, last + 3)
    
'   Get number to increment
    num = Right(entry, Len(entry) - (last + 3)) + 1
    
'   Build next number
    NextNum = prefix & num

End Function
 
Upvote 0
Hi,

Here's a formula solution for what you described:


Book1
ABCD
13/1/2018/XXXX/XXX13/1/2018/XXXX/XXX163/1/2018/XXXX/XXX1163-1-2018-XXXX-XXX116
23/1/2018/XXXX/XXX23/1/2018/XXXX/XXX173/1/2018/XXXX/XXX1173-1-2018-XXXX-XXX117
33/1/2018/XXXX/XXX33/1/2018/XXXX/XXX183/1/2018/XXXX/XXX1183-1-2018-XXXX-XXX118
43/1/2018/XXXX/XXX43/1/2018/XXXX/XXX193/1/2018/XXXX/XXX1193-1-2018-XXXX-XXX119
53/1/2018/XXXX/XXX53/1/2018/XXXX/XXX203/1/2018/XXXX/XXX1203-1-2018-XXXX-XXX120
63/1/2018/XXXX/XXX63/1/2018/XXXX/XXX213/1/2018/XXXX/XXX1213-1-2018-XXXX-XXX121
73/1/2018/XXXX/XXX73/1/2018/XXXX/XXX223/1/2018/XXXX/XXX1223-1-2018-XXXX-XXX122
83/1/2018/XXXX/XXX83/1/2018/XXXX/XXX233/1/2018/XXXX/XXX1233-1-2018-XXXX-XXX123
93/1/2018/XXXX/XXX93/1/2018/XXXX/XXX243/1/2018/XXXX/XXX1243-1-2018-XXXX-XXX124
103/1/2018/XXXX/XXX103/1/2018/XXXX/XXX253/1/2018/XXXX/XXX1253-1-2018-XXXX-XXX125
Sheet181
Cell Formulas
RangeFormula
A2=LEFT(A1,FIND("|",SUBSTITUTE(SUBSTITUTE(A1,"-","/"),"/","|",4))+3)&(RIGHT(A1,LEN(A1)-LEN(LEFT(A1,FIND("|",SUBSTITUTE(SUBSTITUTE(A1,"-","/"),"/","|",4))+3)))+1)


Formula copied down as far as needed.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,849
Members
452,361
Latest member
d3ad3y3

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