Extract A String Between Two Characters

theaudioguy

New Member
Joined
Jan 27, 2010
Messages
27
I'm stuck. I need a formula to extract data from between two characters.

For Example, In A1 I have this: COMP_PROG_v1_ABCD_01

I want to extract the value between the 3rd and 4th "_"'s. The number of "_"'s will be consistent but not the # of characters between them. My brain is tired of thinking. Thanks.
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
HELP

I am trying to do the same as everyone else... Am a novice at this and still getting my head around what the functions achieve so i seem to be doing something fundamentally wrong. If someone can help and also explain what I am doing wrong that would be AMAZING. I will either have a 15 or 21 digit number with 4 "_" separating the different item codes.
Such as
01_001_0101_1_1
OR
03_050903053_0103_1_1

What I have so far is...... I am just not sure where I am going wrong.

<tbody>
</tbody>
To Find "_""_" positionTo extract part of stringTo extract part of string Works
FirstSEARCH("_",A62)3LEFT($A62,SEARCH("_",$A62)-1)01 yes
Second SEARCH("_",A62,SEARCH("_",A62)+1)7LEFT($A62,SEARCH("_",$A62,SEARCH("_",A62)+1))01_001_ No
Third
Fourth
Fifth

<colgroup><col><col><col><col><col><col><col><col></colgroup><tbody>
</tbody>
 
Upvote 0
Welcome to the MrExcel board!

HELP

I will either have a 15 or 21 digit number with 4 "_" separating the different item codes.
Such as
01_001_0101_1_1

OR

03_050903053_0103_1_1
Please clarify what you want extracted from such strings?
That is, what result(s) do you want and where do you want it/them?
 
Upvote 0
I need to extract each part of the string between the "_" into different cells so eg

A1B1C1D1E1F1
01_001_0101_1_101001010111

<colgroup><col><col><col><col><col><col></colgroup><tbody>
</tbody>
 
Upvote 0
I need to extract each part of the string between the "_" into different cells so eg

A1B1C1D1E1F1
01_001_0101_1_101001010111

<colgroup><col><col><col><col><col><col></colgroup><tbody>
</tbody>
With your data in cell A1, put this formula in cell B1 and copy it across...

=TRIM(MID(SUBSTITUTE("_"&$A1,"_",REPT(" ",99)),COLUMNS($B:B)*99,99))

This formula, and its copies across, can all be copied down as needed.
 
Upvote 0
Thank you .. im sure that will work but is there any chance you could explain how it works, I have lots of these kinds of things to do and if I don't understand it I am just going to get stuck again!
 
Upvote 0
.. is there any chance you could explain how it works ..
This is basically the same as Rick's but I'll use this one for my explanation, using "01_001_0101_1_1" as the sample data.

=TRIM(MID(SUBSTITUTE($A1,"_",REPT(" ",100)),COLUMNS($B:B)*100-99,100))

The SUBSTITUTE takes out each of the "_" characters and replaces them with 100 space characters.

When we are in column B, COLUMNS($B:B) is 1 so we have 1*100-99 which gives 1.
So the MID functions extracts from position 1 of the expanded string to position 100. This will be "01" followed by 98 of the first 100 spaces.

TRIM gets rid of the trailing spaces leaving "01" which is the required 1st term

When we are in column C, COLUMNS($B:C) is 2 so we have 2*100-99 which gives 101.
So the MID functions extracts from position 101 of the expanded string to position 200. This will be a couple of spaces from the end of the first 100 spaces followed by "001" followed by about 95 of the second 100 spaces.

TRIM gets rid of the leading & trailing spaces leaving "001" which is the required second term

etc
 
Upvote 0
So there is no way to do this without first adding in all the spaces?
No wonder I couldn't get it... i know nothing about substitution.
 
Upvote 0
So there is no way to do this without first adding in all the spaces?
Sure, other ways are definitely possible. In Excel there is virtually always more than one way to achieve something.
The method suggested by Rick & me was done so because it requires relatively few functions in the formula and the same formula can be used for all result columns.

Just to demonstrate some of the possibilities, here's another formula that can be copied across to all columns, but as you can see it is a much longer formula.

Excel Workbook
ABCDEF
101_001_0101_1_101001010111
203_050903053_0103_1_103050903053010311
Split Text (1)



Another option is for each column to have an individual formula. I'm not suggesting that each of these is the best for its column, but rather showing a variety of possible methods.

Excel Workbook
ABCDEF
101_001_0101_1_101001010111
203_050903053_0103_1_103050903053010311
Split Text (2)




Yet another option for you might be to avoid formulas altogether and use Excel's built-in Text-To-Columns feature found on the Data ribbon tab
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,043
Messages
6,122,825
Members
449,096
Latest member
Erald

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