Extracting numbers from text in excel [Case study]

Share

Facebook
Twitter
LinkedIn

Often we deal with data where numbers are buried inside text and we need to extract them. Today morning I had such task. As you know, we recently ran a survey asking how much salary you make. We had 1800 responses to it so far. I took the data to Excel to analyze it. And surprise! the numbers are a mess. Here is a sample of the data.

Extract numbers from text in Excel - How to?

Now, how do I extract the salary amounts from this without typing the values?

My first thought is to write a user defined function to extract the number from text. But I usually shy away from VBA. So I wanted to see if there is a formula based approach to extract the number from text.

Using formulas to extract number from text

Extracting numbers from text using Excel formulas - process

To extract number from a text, we need to know 2 things:

  1. Starting position of the number in text
  2. Length of the number

For example, in text US $ 31330.00 the number starts at 6th letter and has a length of 8.

So, if we can write formulas to get 1 & 2, then we can combine them in MID formula to extract the number from text!

Finding the starting position of number in text

To find the starting position, we need to find the first character which is a number (0 to 9). In other words, if we can find the positions of 0 to 9 inside the given text, then the minimum of all such positions would be starting position.

Sounds complicated?!? Well, in that case look at the formula and then you will understand why this works.

Assuming the text is in A1 and the range lstNumbers contains 0 to 9, below formula finds starting position

{=MIN(IFERROR(FIND(lstNumbers,A1),””))}

You need to array enter it (CTRL+SHIFT+Enter)

How this formula works?

FIND(lstNumbers, A1) portion: This part finds where each of the numbers 0 to 9 occur in the text in A1. If a match is found, the position is returned. Else we get an error. For US $ 31330.00 the values would be,

{10;7;#VALUE!;6;#VALUE!;#VALUE!;#VALUE!;#VALUE!;#VALUE!;#VALUE!}

Meaning, 0 occurs at 10th position, 1 occurs at 7th position, 3 occurs at 6th position and everything else (2,4,5,6,7,8,9) do not occur in the number.

IFERROR(…,””) portion: Then, we replace errors with empty spaces so that MIN could work its magic.

At this stage, the result would be, {10;7;””;6;””;””;””;””;””;””}

Related: IFERROR Formula – syntax & examples

{=MIN(…)} portion: This would find the minimum of {10;7;””;6;””;””;””;””;””;””} which is 6. The starting position of number inside text.

Because we are finding multiple items, we need to array enter the formula to get correct result.

Finding the length of number

Once we find starting point, next we need to know the length of the number. There are many ways to do this. Depending on the variety in your input data, you can choose a technique that works best.

Approach 1 – counting number of digits in text

My first approach is to count number of digits in the text and use it as length. For this, we can break the text in to individual characters and then see if each of them is a number or not.

Assuming the text is in A1, the number of digits in it are,

=SUMPRODUCT(- -ISNUMBER(MID(A1,ROW($A$1:$A$200),1)+0))

MID(A1,ROW($A$1:$A$200),1) + 0 portion: This breaks the text in A1 in to individual characters (assumes the max length is 200) and then adds 0 to them.

At this stage, you have 200 values some of them numbers, others errors.

ISNUMBER(…) portion: This checks all the 200 values for numbers. After this, we will have 200 true or false values.

— ISNUMBER (…) portion: This converts the true, false values to 0s and 1s. (by double negating Excel will convert boolean values to number equivalents).

SUMPRODUCT(…) portion: This finally sums up all 1s thus giving us the number of digits in the text.

Does it work?

While this approach works well for some numbers, it fails in other cases. For example, a text like US $ 31330.00 has number portion with 8 characters (31330.00) where as our formula would say the length is 7 (because decimal point . is not a number and hence ISNUMBER() would give false for that).

So I had to move on to next approach.

Approach 2 – counting number of digits, commas & decimal points in text

The next approach is to count not only numbers, but also commas & decimal points in the text. For this, first I placed all the digits (0 to 9) and comma & decimal point in a range called as lstDigits.

Below formula counts how many of lstDigits are in text in A1.

=SUMPRODUCT(COUNTIF(lstDigits,MID(A1,ROW($A$1:$A$200),1)))

COUNTIF(lstDigits, MID(…)) portion: This checks how many times each of the 200 characters appear in lstDigits.

This would be an array of counts. For example {0;0;0;0;0;1;1;1;1;1;1;1;1;…} for US $ 31330.00, indicating that first 5 are not in lstDigits and then we have 8 in lstDigits.

SUMPRODUCT(…) portion: just sums all the numbers, hence we get length as 8.

Related: SUMPRODUCT Formula – examples & explanation

Extract numbers from text in excel - results explained

Extracting numbers from text

Once we have starting position of number & its length, we can combine them in a MID formula to extract the number. Here is the result for our sample data set.

As you can see, this method works well, but fails in some cases like,

  • European number formats (, for decimal point and . for thousands)
  • Text with multiple numbers

Fortunately, in my data set, we had only a few incidents like these. So I have decided to manually adjust them than work out even more complicated formula.

Using Macros to extract numbers from text

As you can guess, we can use a simple macro (or UDF) to extract numbers from a given text. We will learn how to do this next week.

Download Example Workbook

Click here to download example workbook with all these formulas. Examine the formulas to understand how you can extract numbers from text in Excel.

How do you Extract numbers from Text?

Often I deal with data like this. I use a mix of techniques. Apart from the one mentioned above I also use,

  • getNumber() UDF to extract numbers from text (more on this next week)
  • Use SUBSTITUTE to clear formatting (replace dots with empty spaces and commas with dots to convert from European format to standard format)
  • Use VALUE to extract the number (works when number is shown as text)
  • Use +0 to force convert numbers from text (works when number is shown as text)

What about you? How do you extract numbers from text? What are your favorite techniques? Please share using comments.

Tips on cleaning data using Excel

If you use Excel to clean data, go thru these articles to learn some powerful techniques.

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Overall I learned a lot and I thought you did a great job of explaining how to do things. This will definitely elevate my reporting in the future.
Rebekah S
Reporting Analyst
Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

13 Responses to “Using pivot tables to find out non performing customers”

  1. David Onder says:

    To avoid the helper column and the macro, I would transpose the data into the format shown above (Name, Year, Sales).  Now I can show more than one year, I can summarize - I can do many more things with it.  ASAP Utilities (http://www.asap-utilities.com) has a new experimental feature that can easily transpose the table into the correct format.  Much easier in my opinion.

    David 

    • Chandoo says:

      Of course with alternative data structure, we can easily setup a slicer based solution so that everything works like clockwork with even less work.

  2. Martin says:

    David, I was just about to post the same!
    In Contextures site, I remember there's a post on how to do that. Clearly, the way data is layed out on the very beginning is critical to get the best results, and even you may thinkg the original layout is the best way, it is clearly not. And that kind of mistakes are the ones I love ! because it teaches and trains you to avoid them, and how to think on the data structure the next time.
     
    Eventually, you get to that place when you "see" the structure on the moment the client tells you the request, and then, you realized you had an ephiphany, that glorious moment when data is no longer a mistery to you!!!
     
    Rgds,

  3. JMarc says:

    Chandoo,
    If the goal is to see the list of customers who have not business from yearX, I would change the helper column formula to :  =IF(selYear="all",sum(C4:M4),sum(offset(C4:M4,,selyear-2002,1,columns(C4:M4)-selyear+2002)))
     This formula will sum the sales from Selected Year to 2012.

    JMarc

  4. Elias says:

    If you are already using a helper column and the combox box runs a macro after it changes, why not just adjust the macro and filter the source data?
     
    Regards

  5. RichW says:

    I gotta say, it seems like you are giving 10 answers to 10 questions when your client REALLY wants to know is: "What is the last year "this" customer row had a non-zero Sales QTY?... You're missing the forest for the trees...
    Change the helper column to:
    =IFERROR(INDEX(tblSales[[#Headers],[Customer name]:[Sales 2012]],0,MATCH(9.99999999999999E+307,tblSales[[#This Row],[Customer name]:[Sales 2012]],1)),"NO SALES")
    And yes, since I'm matching off of them for value, I would change the headers to straight "2002" instead of "Sales 2002" but you sort the table on the helper column and then and there you can answer all of your questions.

  6. Kevin says:

    Hi thanks for this. Just can't figure out how you get the combo box to control the pivot table. Can you please advise?
     
    Cheers

  7. Kevin says:

    Thanks Chandoo. But I know how to insert a combobox, I was more referring to how does in control the year in the pivot table? Or is this obvious?  I note that if I select the Selected Year from the PivotTable Field List it says "the field has no itens" whereas this would normally allow you to change the year??
     
    Thanks again

  8. Kevin says:

     
    worked it out thanks...
    when =data!Q2 changes it changes the value in column N:N and then when you do a refreshall the pivottable vlaues get updated 
     
    Still not sure why PivotTable Field List says “the field has no itens"?? I created my own pivot table and could not repeat that.

  9. Bermir says:

    Hi, I put the sales data in range(F5:P19) and added a column D with the title 'Last sales in year'. After that, in column D for each customer, the simple formula

    =2000+MATCH(1000000,E5:P5)

    will provide the last year in which that particular customer had any sales, which can than easily be managed by autofilter.

    • Bermir says:

      Somewhat longer but perhaps a bit more solid (with the column titles in row 4):

      =RIGHT(INDEX($F$4:$P$19,1,MATCH(1000000,F5:P5)),4)

Leave a Reply