SOLVED

Returning Text from a data cell

Copper Contributor

Hi all,

 

I have been trying to find a set of formulas that will extract certain numbers or text from data cells and returns them to a separate column but I have had no luck so far. This is an excerpt from the data I am using:

US351-4W
GER195-6Mo
GER529-2Mo
AUS301-7Mo
GER60-3W
ENG102-8Mo
ENG342-10Mo
GER442-10M
Japan17-8W
Canada559-11Mo
ARG389-11Mo
Canada121-12M

 

I need to be able to extract the numbers to the right of the dash in its own column (Ex: Japan17-8W I need to display just the number 8), and I also need to be able to display the letters at the end of the data in its own column ( Ex: ARG389-11Mo I need to display just the Mo). These two formulas need to work regardless of the length of the number or how long the series of letters at the end are. I am stuck and could really use some help! Many Thanks

 

10 Replies
Try Flash Fill.
I need to have formulas in case any extra data comes in. These cells do not have a set pattern to them as it can have several numbers or letters to them based on where the data comes in from.

@danielS1275 

 

This isn't the most elegant of solutions (it could be more efficient to use the new LET function to eliminate redundancy, but then you'd have to have that most recent version of Excel).

 

Here's the formula that gets the letter(s)

=IFS(RIGHT(A$1,1)="W","W",RIGHT(A$1,1)="M","M",RIGHT(A$1,2)="Mo","Mo")

 

Here's the formula that gets the number.

=IFS(RIGHT(A1,1)="W",VALUE(MID(A1,FIND("-",A1)+1,FIND("W",A1)-(FIND("-",A1)+1))),RIGHT(A1,1)="M",VALUE(MID(A1,FIND("-",A1)+1,FIND("M",A1)-(FIND("-",A1)+1))),RIGHT(A1,2)="Mo",VALUE(MID(A1,FIND("-",A1)+1,FIND("Mo",A1)-(FIND("-",A1)+1))))

 

@danielS1275 You wrote as a follow-on to your original:

These cells do not have a set pattern to them as it can have several numbers or letters to them based on where the data comes in from.

 

So it's possible that my formulas, based on your original set of examples, would need to be modified to add nuances. But they should point you in the right direction. 

I agree with @Detlef Lewin . Flash Fill is the best solution here.  A lengthy formula can be written but Flash Fill can be summoned with the press of a button at will.

 

So you did not try Flash Fill?

@Detlef Lewin @Patrick2788 

 

It's entirely possible that @danielS1275 doesn't know what Flash Fill is. I didn't, and I'm a regular on these boards. I looked at Excel Help and see that it's available, but haven't tried to figure it out.

 

Might I suggest that one of you give him (and, in the process, me) a pointer or two on how to use it. 

The online help article is the first place to go.
Second step would be a web search and consulting other resources.

If it is a simple pattern, FF will kick in after you typed the second example.
For more complex patterns you may need more examples and/or press CTRL-E.

@danielS1275 

This really need regular expressions but, failing that,

= MAP(data,
      LAMBDA(d,
         LET(
            duration, TEXTAFTER(d, "-"),
            char, MID(duration, SEQUENCE(LEN(duration)), 1),
            num, IFERROR(--char, ""),
          --CONCAT(num)
         )
      )
   )

works in the latest versions of 365.

best response confirmed by danielS1275 (Copper Contributor)
Solution

@danielS1275 

Here are formulas that will work in older versions of Excel too.

With a value such as US351-4W in A1:

=--LEFT(MID(A1, FIND("-", A1)+1, 100), MATCH(FALSE, ISNUMBER(--MID(MID(A1, FIND("-", A1)+1, 100), ROW(INDIRECT("1:"&LEN(MID(A1, FIND("-", A1)+1, 100)))), 1)), 0)-1)

and

=MID(MID(A1, FIND("-", A1)+1, 100),MATCH(FALSE, ISNUMBER(--MID(MID(A1, FIND("-", A1)+1, 100), ROW(INDIRECT("1:"&LEN(MID(A1, FIND("-", A1)+1, 100)))), 1)), 0), 100)

 

1 best response

Accepted Solutions
best response confirmed by danielS1275 (Copper Contributor)
Solution

@danielS1275 

Here are formulas that will work in older versions of Excel too.

With a value such as US351-4W in A1:

=--LEFT(MID(A1, FIND("-", A1)+1, 100), MATCH(FALSE, ISNUMBER(--MID(MID(A1, FIND("-", A1)+1, 100), ROW(INDIRECT("1:"&LEN(MID(A1, FIND("-", A1)+1, 100)))), 1)), 0)-1)

and

=MID(MID(A1, FIND("-", A1)+1, 100),MATCH(FALSE, ISNUMBER(--MID(MID(A1, FIND("-", A1)+1, 100), ROW(INDIRECT("1:"&LEN(MID(A1, FIND("-", A1)+1, 100)))), 1)), 0), 100)

 

View solution in original post