Assistance required

aligahk06

Active Member
Joined
Apr 26, 2009
Messages
257
Dear All,

I have an excel sheet of text string like....
Cell A1 .... employee_code = 25147 and trans_code=16....
Cell A2 .... employee_code = 25112 and trans_code=16....
Cell A3 .... employee_code = 18512 and trans_code=16.... and so on ...
i want to pull employee code from above string in corresponding an excel cell like B1: 25147 B2:25112 and B3:18512
Note - before employee code there is a string and after =16 there is string.

Request for any formula or assistance for solution...

Regards,
aligahk06



 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
This formula in B1 should work, then copy down:

=MID(A1,FIND("employee_code",A1,1)+16,5)

I've kept it simple, so it'll only work whilst the employee code is 5 digits.
 
Last edited:
Upvote 0
If the number of employees is always 5 digits:

=MID(A1,17,5)

If you want the code as a numeric value:

=--MID(A1,17,5)

-------------------------------------------------

If the code has more than 5 digits

=TRIM(MID(SUBSTITUTE(SUBSTITUTE(A1," = ","")," ",REPT(" ",50)),14,50))

If you want the code as a numeric value:

=--TRIM(MID(SUBSTITUTE(SUBSTITUTE(A1," = ","")," ",REPT(" ",50)),14,50))
 
Upvote 0
If the number of employees is always 5 digits:

=MID(A1,17,5)

If you want the code as a numeric value:

=--MID(A1,17,5)

-------------------------------------------------

If the code has more than 5 digits

=TRIM(MID(SUBSTITUTE(SUBSTITUTE(A1," = ","")," ",REPT(" ",50)),14,50))

If you want the code as a numeric value:

=--TRIM(MID(SUBSTITUTE(SUBSTITUTE(A1," = ","")," ",REPT(" ",50)),14,50))

I think you missed this note by the OP where he indicates there is additional text before and after what he showed in his examples...
Note - before employee code there is a string and after =16 there is string.
 
Upvote 0
I think you missed this note by the OP where he indicates there is additional text before and after what he showed in his examples...

Hi Rick, you're right, I omitted that big detail.
If you allow me, I submit a correction, if the employee code is larger than 5 characters.


<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:574.1px;" /><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:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >string before employee code employee_code = 25147 and trans_code=16....</td><td style="text-align:right; ">25147</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >string before employee code more and more employee_code = 25147123 and trans_code=16....</td><td style="text-align:right; ">25147123</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 >B1</td><td >=TRIM(LEFT(SUBSTITUTE(MID(A1,SEARCH("employee_code = ",A1)+16,LEN(A1)), " ",REPT(" ",50)),50))</td></tr></table></td></tr></table>
 
Upvote 0
I thought I'd adapt my formula for any length of employee code - as long as there's always a space character after the code, as in all of your examples:
In B1: =MID(A1,FIND("employee_code",A1,1)+16,FIND(" ",A1,FIND("employee_code",A1,1)+18)-(FIND("employee_code",A1,1)+15)-1)
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,213
Members
448,554
Latest member
Gleisner2

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