Returning variable value

Chloe75

New Member
Joined
Jan 17, 2018
Messages
2
Hello, I have the below text that I would like to extract the person's name (highlighted in bold) who is responsible for "Markup Changes" .. essentially this is the second instance of "responsibility of"


Cell text looks like this

variable text (Responsibility of: surname, firstname, due 13/02/2018 at 10:00 AM (x days, x hours, x minutes)) Insurance Renewal - Markup Changes (Responsibility of: surname, firstname, ....)

The person's name will vary but every line will include the text Markup Changes (Responsibility of: x)

Hoping someone can please assist with a formula to do this.

Many thanks.
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Hi Cloe75

Assuming your text is in Column A, place the following formula in the cells where indicated:

Helper Column (cell B1)
Code:
=RIGHT(A1,(LEN(A1)-(SEARCH("Markup Changes ",A1)+LEN("Markup Changes "))))

firstname (cell C1)
Code:
=TRIM(MID(B1,SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),3)),((SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),4))-1)-SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),3)))))

surname (cell D1)
Code:
=TRIM(MID(B1,(SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),2))),(((SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),3)))-1)-(SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),2))))))

Then copy the range B1:D1 down for as long as there is text in Column A.

Thanks to @Aladin Akyurek for finding out the nth space in a line of text: https://www.mrexcel.com/forum/excel-questions/72148-formula-find-nth-space-text-string.html

My proposed solution may not be as elegant as a UDF but it works on your example.

Cheers

pvr928
 
Upvote 0
Hi Cloe75

Assuming your text is in Column A, place the following formula in the cells where indicated:

Helper Column (cell B1)
Code:
=RIGHT(A1,(LEN(A1)-(SEARCH("Markup Changes ",A1)+LEN("Markup Changes "))))

firstname (cell C1)
Code:
=TRIM(MID(B1,SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),3)),((SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),4))-1)-SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),3)))))

surname (cell D1)
Code:
=TRIM(MID(B1,(SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),2))),(((SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),3)))-1)-(SEARCH(CHAR(127),SUBSTITUTE(B1," ",CHAR(127),2))))))

Then copy the range B1:D1 down for as long as there is text in Column A.

Thanks to @Aladin Akyurek for finding out the nth space in a line of text: https://www.mrexcel.com/forum/excel-questions/72148-formula-find-nth-space-text-string.html

My proposed solution may not be as elegant as a UDF but it works on your example.

Cheers

pvr928



Hello pvr928

Thank you kindly your solution worked a treat!

Very much appreciated.

Chloe
 
Upvote 0

Forum statistics

Threads
1,213,544
Messages
6,114,249
Members
448,556
Latest member
peterhess2002

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