Extract Data from within a cell

chadlaw32

Board Regular
Joined
Jul 29, 2014
Messages
84
Office Version
  1. 365
  2. 2019
  3. 2016
Platform
  1. Windows
I have a sheet that I will update weekly and one of the columns contains data like this "75 Modems Offline txmex001cme - cable-mac 38 · Node 10A1 & 2B2" The numbers at the from could be anything. How do I extract this part txmex001cme without using text to columns. I want to be able to paste data every week and have the sheet do all the work for me.
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Can you provide us with some guidelines we can use to identify what exactly we are looking for to extract?
Is there some common theme or part that we need to look for?

It would also be helpful to provide us with a few more different examples, so we have a better idea of how different your data may look, and what you are looking for in each one.
Otherwise, you may end up with a solution that works for the one specific example you posted, and not all your other data.
Try to give us a good representative sample of the different possibilities.
 
Upvote 0
This is an example of the data. I need everything after Offline but before the -


9 Modems Offline ardeq001cmj - CATV-MAC 3 · DQ002()
29 Modems Offline - C42/F22 - Rutherfordton, NC
76 Modems Offline okcho001cmh - CATV-MAC 26 · PR07B()
129 Modems Offline ncfrc001cme - cable-mac 11 · CMAC 11
48 Modems Offline okket001cme - cable-mac 121 · cable-mac_121_nodes_K002,K012
 
Upvote 0
This is an example of the data. I need everything after Offline but before the -
Your second example has the "-" immediately after the word "Offline".
29 Modems Offline - C42/F22 - Rutherfordton, NC

So according to your rule above, this record shouldn't return anything, right?
 
Upvote 0
I need it to take the date below
9 Modems Offline ardeq001cmj - CATV-MAC 3 · DQ002()
29 Modems Offline - C42/F22 - Rutherfordton, NC
76 Modems Offline okcho001cmh - CATV-MAC 26 · PR07B()
129 Modems Offline ncfrc001cme - cable-mac 11 · CMAC 11
48 Modems Offline okket001cme - cable-mac 121 · cable-mac_121_nodes_K002,K012

and return the data below

ardeq001cmj
C42/F22
okcho001cmh
ncfrc001cme
okket001cme
 
Last edited by a moderator:
Upvote 0
OK, the best guess I can make is that you want the first full word after the word "Offline" (so exclude "-" if it is the first thing that follows "Offline").
For an entry in cell A1, the formula would look like this:
Excel Formula:
=TRIM(MID(SUBSTITUTE(SUBSTITUTE(A1,"Offline -","Offline"),"-",REPT(" ",100)),FIND("Offline",SUBSTITUTE(A1,"Offline -","Offline"))+8,100))
 
Upvote 0
Solution

Forum statistics

Threads
1,213,543
Messages
6,114,236
Members
448,555
Latest member
RobertJones1986

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