Extract variable length text from a string

gpsurf

Board Regular
Joined
Feb 20, 2008
Messages
96
I have been forking on solving an problem extracting a specific portion of a text from a string.

Here is a few examples of the text format that is in column A:

Invoice: PST-53012-IN:CID:XYZ10010819: id Month (

Payment: 100272-CR:CID:XYZ192:

Payment: 19313-CR:CID:XYZ10014254:
Payment: 3660-CR:CID:xyz10015999:



<COLGROUP> <COL style="WIDTH: 233pt; mso-width-source: userset; mso-width-alt: 11337" width=310> <TBODY>
</TBODY>
I need to extract the text (invoice #) between the colons that begins with xyz. The string size is variable and the invoice may be in capital or lower case. Also the invoice number is not the always the same length. One consistent variable is that before the Invoice # always has the text “CID:” and it ends with a colon.<o:p></o:p>
I am looking for a formula solution instead of a VBA solution.<o:p></o:p>
<o:p> </o:p>
I have tried this solution but it just does not give me all the values I need =+MID(A10,FIND("XYZ",A10),11)<o:p></o:p>
<o:p> </o:p>
Any ideas you have would be greatly appreciated.<o:p></o:p>
<o:p> </o:p>
Thanks<o:p></o:p>
George<o:p></o:p>


</SPAN>

<TBODY>
</TBODY><COLGROUP> <COL> </COLGROUP>

<COLGROUP> <COL style="WIDTH: 233pt; mso-width-source: userset; mso-width-alt: 11337" width=310> <TBODY>
</TBODY>

<COLGROUP><COL style="WIDTH: 233pt; mso-width-source: userset; mso-width-alt: 11337" width=310><TBODY>
</TBODY>
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
One way:
PST-53012-IN:CID:XYZ10010819: id Month (XYZ10010819
Payment: 100272-CR:CID:XYZ192:XYZ192
Payment: 3660-CR:CID:xyz10015999:xyz10015999
Payment: 19313-CR:CID:XYZ10014254:XYZ10014254
Payment: 19313-CR:fdfadf:fdf:CID:XYZ10014254 :XYZ10014254
dfasd;fl:fadsfasd:908709804:CID:XYZ:fadfafdf;XYZ

<tbody>
</tbody>

=TRIM(LEFT(MID(A1,FIND("CID",A1)+4,LEN(A1)),FIND(":",MID(A1,FIND("CID",A1)+4,LEN(A1)))-1))
 
Upvote 0
That worked, thank you! I just have to figure out how it works I haven't combined these functions together like this before.
 
Upvote 0
A bit shorter formula :

=MID(A1,FIND("CID",A1)+4,FIND(":",A1,FIND("CID",A1)+4)-FIND("CID",A1)-4)

Regards
 
Upvote 0

Forum statistics

Threads
1,215,123
Messages
6,123,182
Members
449,090
Latest member
bes000

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