Return value of cell in range if it begins with...

Damo71

Board Regular
Joined
Aug 17, 2010
Messages
88
Hi

I will periodically be pasting the contents of a web page in cell A1 (the paste execution will actually spread the info from A1 down to about A100) The web page always has specific headers which usually paste to the same lines but not always.

So in cell B1 I need a formula to look at the range A1 to A100, and return the text that Begins with, say, the word "Introduction"

Then in B2 and B3. I need the formulae to return the text from the first and second rows (respectively) under the cell that began with the word "Introduction".

(There are several other headers that I will be extracting also, but I can apply the same principle once I've learned how to do it.)

For Example
Imagine I paste from the site and there's a line that reads: "Introduction: Why we must always pay attention" That string has pasted onto A8 this time. In A9 there appears the text "Because it shows respect", and in A10: "You will get better grades if you do".

B1 looks through A1:A100 for the line that begins "Introduction" (there will always be a string that begins this way) and locates it in A8 and returns "Introduction: Why we must always pay attention"
B2 needs to return "Because it shows respect"
B3 needs to return "You will get better grades if you do"
As the latter two strings will be different each time, I cannot search for a string but must return an offset result 1 and 2 cells below the cell that began with "Introduction"

Thanks

Damo
 
Last edited:

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
Hi,

Here are 3 formulas that match the example you specified.

Ctrl+Shift+Enter NOT just Enter

B1 =INDEX($A$1:$A$100,MATCH(1,--ISNUMBER(SEARCH("Introduction",LEFT($A$1:$A$100,12))),0))
B2 =INDIRECT("A"&MATCH(1,--ISNUMBER(SEARCH("Introduction",LEFT($A$1:$A$100,12))),0)+ROW(A1))
B3 =INDIRECT("A"&MATCH(1,--ISNUMBER(SEARCH("Introduction",LEFT($A$1:$A$100,12))),0)+ROW(A2))


[TABLE="width: 803"]
<colgroup><col><col><col></colgroup><tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]AAA[/TD]
[TD]Introduction: Why we must always pay attention[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]BBB[/TD]
[TD]Because it shows respect[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]CCC[/TD]
[TD]You will get better grades if you do[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]DDD[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]AAA[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]BBB[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]CCC[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]DDD[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]AAA[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]BBB[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]11[/TD]
[TD]AAAA Introduction: Why we must always pay attention[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DDD[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]13[/TD]
[TD]AAA[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]14[/TD]
[TD]BBB[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]15[/TD]
[TD]CCC[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]16[/TD]
[TD]DDD[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]17[/TD]
[TD]Introduction: Why we must always pay attention[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]18[/TD]
[TD]Because it shows respect[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]19[/TD]
[TD]You will get better grades if you do[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]20[/TD]
[TD]BBBB[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0

Forum statistics

Threads
1,223,713
Messages
6,174,043
Members
452,542
Latest member
Bricklin

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