Two numbers to left of * and two numbers to right of *

spencer_time

New Member
Joined
Sep 19, 2019
Messages
41
Hello,

I -had- part of my program working until I realized that the length of the filename wasn't always constant and I need help fixing that.
In the following section of code it used to look for a sheet names *CEQ* and extract the two numbers before CEQ and the two numbers after CEQ. I then started trying to make it more universal to work in my final application and swapped CEQ for the variable "response" (which gets its value from a user form and can be 1-6 characters, all letters) but then my MID functions to extract the 2 (maybe occasionally 3) numbers before and after the response variable will no longer work.

Code:
    If curSheet.Name Like "*" & response & "*" Then
        partNum = Mid(curSheet.Name, 1, 2) 'extract part number from filename to use in specifying where to save other information into array
        dataSet(3, 0, partNum, designator) = Mid(curSheet.Name, 6) 'extract dB value from filename and save to dataset array
        dataSet(9, 0, partNum, designator) = Mid(curSheet.Name, 1, 2) 'extract part number from filename and save to dataset array
Is there a way to make the program not care if the sheet name is 105CEQ33 or 08CEQ4, and always extract the number before and the number after the the letters and save them into separate variables?

Thanks in advance.
 

Some videos you may like

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
10,194
Office Version
2007
Platform
Windows
Try this

Code:
Sub test()
  Dim response As String, part1 As String, part2 As String
  Dim curSheet As Worksheet
  Set curSheet = ActiveSheet
  response = "CEQ"
  If curSheet.Name Like "*" & response & "*" Then
    part1 = Left(curSheet.Name, InStr(1, curSheet.Name, response) - 1)
    part2 = Mid(curSheet.Name, InStr(1, curSheet.Name, response) + Len(response))
  End If
End Sub
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
35,652
Office Version
2010
Platform
Windows
Another way to consider...
Code:
Sub test()
  Dim Response As String, Parts() As String
  Response = "CEQ"
  Parts = Split(ActiveSheet.Name, Response)
  If UBound(Parts) Then
[B][COLOR="#008000"]    ' Parts(0) will contain the number before the Response
    ' Parts(1) will contain the number after the Response[/COLOR][/B]
  End If
End Sub
 

spencer_time

New Member
Joined
Sep 19, 2019
Messages
41
Thanks for your help guys, both of these appear to work. I'm going to go with DanteAmor's suggestion as I understand it better and can troubleshoot it if something goes wrong, but I will save your suggestion too Rick Rothstein, and once I'm done with my big spreadsheet will play around with it and see if it might can be used to make my spreadsheet any better.
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
10,194
Office Version
2007
Platform
Windows
I'm glad to help you. Thanks for the feedback.
 

Forum statistics

Threads
1,089,477
Messages
5,408,478
Members
403,209
Latest member
JRocket1207

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top