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.
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
9,524
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,558
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
9,524
Office Version
2007
Platform
Windows
I'm glad to help you. Thanks for the feedback.
 

Forum statistics

Threads
1,084,743
Messages
5,379,560
Members
401,613
Latest member
KarimK9

Some videos you may like

This Week's Hot Topics

  • VBA code giving errors and stopping Excel
    Hello Experts, I have this code being used to loop through files in a file path, and copy specific data to another sheet. It is giving me several...
  • Disable MsgBox message
    Morning, I have a userform where if i leave a ComboBox empty i see a MsgBox warning me that i must enter an invoice number. It is this MsgBox i...
  • Macro Recorder into VBA, Copy Paste Data Filled Cells
    Hi Everyone, I have a macro recorder file that takes a selection of data, copies, then pastes into a new sheet on ("A2:B2") The issue is my...
  • Number format changes while pasting into a cell
    Hi, I am trying to paste a number 180204524303 from an email to an excel cell, however, whenever i try to do so , the the paste value appears as...
  • Collating data
    Hello all. Could someone please help. I am trying to pull all column data from multiple sheets (24 I total so far) into 1 master sheet without...
  • Sum Multiple Columns Based on Multiple Criteria
    I am trying to consolidate data by summing columns G through M based on material, plant, vendor, and fiscal year being identical. The period does...
Top