Search row for keyword and build a new table with values

mejohn

New Member
Joined
Jun 23, 2018
Messages
31
Office Version
  1. 365
Platform
  1. Windows
Hello, I have some data in rows but they are not organized in the proper columns.
I'd like to search the row for keywords, parse and extract the information in the cell to build a new table.

Here's an example of the raw data:

ABC
1$2.50desert: Cakepoints:200
2points: 100$1.50desert: Ice cream

<tbody>
</tbody>
I would like a the data extracted under the headings "Desert", "Price" and Points. For example under the heading Desert, I would like the formula to search the first row of the raw data and return "Cake" in A2," $2.50" in B2 and "200" in C2. The same for the other rows in the data.

<tbody>
</tbody>
ABC
1DesertPricePoints
2Cake$2.50200
3Ice cream$1.50100

<tbody>
</tbody>
Thank you.

<tbody>
</tbody>

<tbody>
</tbody>

<tbody>
</tbody>
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
I put 3 array formulas.


<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:70.34px;" /><col style="width:79.84px;" /><col style="width:108.36px;" /><col style="width:76.04px;" /><col style="width:79.84px;" /><col style="width:76.04px;" /><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><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td > </td><td > </td><td > </td><td style="background-color:#92d050; text-align:center; ">Desert</td><td style="background-color:#92d050; text-align:center; ">Price</td><td style="background-color:#92d050; text-align:center; ">Points</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">2.5</td><td >desert: Cake</td><td >points:200</td><td > </td><td >Cake</td><td style="text-align:right; ">2.5</td><td style="text-align:right; ">200</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >points: 100</td><td style="text-align:right; ">1.5</td><td >desert: Ice cream</td><td > </td><td >Ice cream</td><td style="text-align:right; ">1.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 >Array Formula</td></tr><tr><td >E2</td><td >{=REPLACE(INDEX($A2:$C2,0,MAX(ISNUMBER(SEARCH(E$1,$A2:$C2))*COLUMN($A2:$C2))),1,8,"")}</td></tr><tr><td >F2</td><td >{=MAX(IF(ISNUMBER(A2:C2),A2:C2))}</td></tr><tr><td >G2</td><td >{=--REPLACE(INDEX($A2:$C2,0,MAX(ISNUMBER(SEARCH(G$1,$A2:$C2))*COLUMN($A2:$C2))),1,7,"")}</td></tr></table></td></tr></table>


The data in column A, B, D should start in row 2.
 
Upvote 0
Hi,

Another way, all formulas normally entered:


Book1
ABC
1$2.50desert: Cakepoints:200
2points: 100$1.50desert: Ice cream
3
4
5DesertPricePoints
6Cake$2.50200
7Ice cream$1.50100
Sheet699
Cell Formulas
RangeFormula
A6=TRIM(LOOKUP(2,1/SEARCH(A$5,A1:C1),MID(A1:C1,SEARCH(A$5,A1:C1)+7,99)))
B6=LOOKUP(2,1/ISNUMBER(A1:C1),A1:C1)
C6=LOOKUP(2,1/SEARCH(C$5,A1:C1),MID(A1:C1,SEARCH(C$5,A1:C1)+7,99))+0


Change/adjust cell references/range as needed, formulas copied down columns.
 
Upvote 0
I change my array formulas to regular formula.


The formula in column E and G is the same. You can copy the column of E2 down and then copy all the formulas of E in column G.

<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:70.34px;" /><col style="width:79.84px;" /><col style="width:108.36px;" /><col style="width:76.04px;" /><col style="width:160.63px;" /><col style="width:76.04px;" /><col style="width:159.68px;" /></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><td >F</td><td >G</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td > </td><td > </td><td > </td><td style="background-color:#92d050; text-align:center; ">Desert</td><td style="background-color:#92d050; text-align:center; ">Price</td><td style="background-color:#92d050; text-align:center; ">Points</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">2.5</td><td >desert: Cake</td><td >points:200</td><td > </td><td >Cake</td><td style="text-align:right; ">2.5</td><td style="text-align:right; ">200</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >points: 100</td><td style="text-align:right; ">1.5</td><td >desert: Ice cream</td><td > </td><td >Ice cream</td><td style="text-align:right; ">1.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 >E2</td><td >=TRIM(MID(HLOOKUP("*"&E$1&"*",$A2:$C2,1,0),LEN(E$1)+2,250))</td></tr><tr><td >F2</td><td >=HLOOKUP(9^9,A2:C2,1,1)</td></tr><tr><td >G2</td><td >=TRIM(MID(HLOOKUP("*"&G$1&"*",$A2:$C2,1,0),LEN(G$1)+2,250))</td></tr></table></td></tr></table>
 
Upvote 0
Just realized my B Column formula from Post # 3 can be written shorter, either B6 or B7 below:


Book1
ABC
1$2.50desert: Cakepoints:200
2points: 100$1.50desert: Ice cream
3
4
5DesertPricePoints
6Cake$2.50200
7Ice cream$1.50100
Sheet699
Cell Formulas
RangeFormula
B7=-LOOKUP(1,-(A2:C2))
B6=LOOKUP(9.99999999999999E+307,A1:C1)
A6=TRIM(LOOKUP(2,1/SEARCH(A$5,A1:C1),MID(A1:C1,SEARCH(A$5,A1:C1)+7,99)))
C6=LOOKUP(2,1/SEARCH(C$5,A1:C1),MID(A1:C1,SEARCH(C$5,A1:C1)+7,99))+0
 
Upvote 0
Solution
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,557
Latest member
richa mishra

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