extract data between values based on seperate input

Martynrbell

New Member
Joined
Apr 11, 2016
Messages
38
Office Version
  1. 365
Platform
  1. Windows
I have some data in A1 that looks like the following:

PA1*COL 1*50*Snack 1
PA2*3*100*1*100
PA1*COL 2*100*Snack 2
PA2*52*100*0*0
PA1*COL 3*100*Snack 3
PA2*2*200*1*100
PA1*COL 4*50*Snack 4
PA2*7*50*0*0
PA1*COL 5*200*Snack 5
PA2*100*0*0*0

In A2 i need to be able to type a value, in this example i will use "COL 3" and my with the formula will search for PA1*COL 3* return the number after the following PA2* in this example it will be "2"

So if i was to type in A2 the following examples it would return the example values
Col 1 Returns 3
Col 2 Returns 52
Col 3 Returns 2
Col 4 Returns 7
Col 5 Returns 100

Any help would be apreciated

Thanks
Martyn
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Try


<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:197.7px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td></tr><tr style="height:185px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >PA1*COL 1*50*Snack 1<br />PA2*3*100*1*100<br />PA1*COL 2*100*Snack 2<br />PA2*52*100*0*0<br />PA1*COL 3*100*Snack 3<br />PA2*2*200*1*100<br />PA1*COL 4*50*Snack 4<br />PA2*7*50*0*0<br />PA1*COL 5*200*Snack 5<br />PA2*100*0*0*0</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >COL 1</td><td style="text-align:right; ">3</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >COL 2</td><td style="text-align:right; ">52</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >COL 3</td><td style="text-align:right; ">2</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >COL 4</td><td style="text-align:right; ">7</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >COL 5</td><td style="text-align:right; ">100</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >B2</td><td >=LEFT(SUBSTITUTE(REPLACE($A$1,1,SEARCH("PA2",$A$1,SEARCH(A2,$A$1))+3,""),"*",REPT(" ",99)),99)+0</td></tr></table></td></tr></table>
 
Upvote 0
Thanks Dante
That works perfectly...
One more thing to pick your brain on regarding this.

Ive figured out that if i increase the +3 in SEARCH(A2,$A$1))+3 in increments of two i can get the next values along,
this is the case until i use +9 to get the last value, then i get an error.
Is there an easy way to return that last value on the line without majorly changing the formula?

THanks again

Martyn


 
Upvote 0
Thanks Dante
That works perfectly...
One more thing to pick your brain on regarding this.
Ive figured out that if i increase the +3 in SEARCH(A2,$A$1))+3 in increments of two i can get the next values along,
this is the case until i use +9 to get the last value, then i get an error.
Is there an easy way to return that last value on the line without majorly changing the formula?
THanks again
Martyn

I hope this helps you:

Copy to the right and then down.

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:211.96px;" /><col style="width:70.34px;" /><col style="width:70.34px;" /><col style="width:70.34px;" /><col style="width:70.34px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td></tr><tr style="height:185px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >PA1*COL 1*50*Snack 1<br />PA2*3*100*1*100<br />PA1*COL 2*100*Snack 2<br />PA2*52*100*0*0<br />PA1*COL 3*100*Snack 3<br />PA2*2*200*1*100<br />PA1*COL 4*50*Snack 4<br />PA2*7*50*0*0<br />PA1*COL 5*200*Snack 5<br />PA2*100*0*0*0</td><td >Value 1</td><td >Value 2</td><td >Value 3</td><td >Value 4</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >COL 1</td><td style="text-align:right; ">3</td><td style="text-align:right; ">100</td><td style="text-align:right; ">1</td><td style="text-align:right; ">100</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >COL 2</td><td style="text-align:right; ">52</td><td style="text-align:right; ">100</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >COL 3</td><td style="text-align:right; ">2</td><td style="text-align:right; ">200</td><td style="text-align:right; ">1</td><td style="text-align:right; ">100</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >COL 4</td><td style="text-align:right; ">7</td><td style="text-align:right; ">50</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >COL 5</td><td style="text-align:right; ">100</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >B2</td><td >=TRIM(MID(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(REPLACE($A$1,1,SEARCH("PA2",$A$1,SEARCH($A2,$A$1))+2,""),"PA1",""),CHAR(10),""),"*",REPT(" ",50)),50*COLUMNS($C$1:C1),50))+0</td></tr></table></td></tr></table>
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,634
Messages
6,120,659
Members
448,975
Latest member
sweeberry

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