Skip to content
Free Excel Tutorials
  • Home
  • Excel For Beginners
  • Excel Intermediate
  • Advanced Excel For Experts

Data Analysis

  • How to count table rows in Excel
  • How To Remove Duplicates In Excel Column Or Row?
  • Conditional Formatting Rules in Excel
  • Excel Bar Chart
  • Conditional Formatting Data bars Examples in Excel

References

  • How to use Excel OFFSET function
  • How to use Excel VLOOKUP Function
  • To count total rows in a range in Excel
  • How to get last row in numeric data in Excel
  • VLOOKUP function: Description, Usage, Syntax, Examples and Explanation

Data Validations

  • Excel Data validation specific characters only
  • Excel Data validation must contain specific text
  • Excel Data validation allow weekday only
  • Excel Data validation exists in list
  • Excel Data validation whole percentage only

Split numbers from units of measure in Excel

by

To split a number from a unit value, you need to determine the position of the last number. If you add 1 to that position, you have the start of the unit text.

Note: these is an experimental formula that uses a hard coded array constant, set down here for reference and comment. Casually tested only, so take care if you use or adapt.

Sometimes you encounter data that mixes units directly with numbers (i.e. 8km, 12v, 7.5hrs). Unfortunately, numbers in this format are considered to be text inside of Excel,  and you won’t be able to perform any math operations on such values.

Formula

=MAX(ISNUMBER(VALUE(MID(A1,{1,2,3,4,5,6,7,8,9},1)))*{1,2,3,4,5,6,7,8,9})+1

Explanation

 

In the example shown, the formula in C5 is:

=MAX(ISNUMBER(VALUE(MID(B5,{1,2,3,4,5,6,7,8,9},1)))*{1,2,3,4,5,6,7,8,9})+1

This formula uses the MID function to extract the first 9 values in B5, one character at a time. The result is an array like this:

{“8″,”0″,”v”,””,””,””,””,””,””}

We then use the VALUE function to convert numbers in text format to actual numbers. The result is:

{8,0,#VALUE!,#VALUE!,#VALUE!,#VALUE!,#VALUE!,#VALUE!,#VALUE!}

We run this array through ISNUMBER to get:

{TRUE,TRUE,FALSE,FALSE,FALSE,FALSE,FALSE,FALSE,FALSE}

Then multiply that times another array with 9 numbers to get:

{1,2,0,0,0,0,0,0,0}

Then we use MAX to get the largest value, which is the position of the “last number”.

In this case we add 1 to the position to get the “unit start” position.

Finally, we use this position with standard LEFT and RIGHT functions to separate the numbers from the units:

=VALUE(LEFT(B5,C5-1)) // number
=TRIM(RIGHT(B5,LEN(B5)-C5+1)) // unit

Note that the hard-coded number array constant is a hack for convenience, and will only handle raw values up to 9 characters in length.

Post navigation

Previous Post:

DECIMAL function: Description, Usage, Syntax, Examples and Explanation

Next Post:

AVERAGE function: Description, Usage, Syntax, Examples and Explanation

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Learn Basic Excel

Ribbon
Workbook
Worksheets
Format Cells
Find & Select
Sort & Filter
Templates
Print
Share
Protect
Keyboard Shortcuts

Categories

  • Charts
  • Data Analysis
  • Data Validation
  • Excel Functions
    • Cube Functions
    • Database Functions
    • Date and Time Functions
    • Engineering Functions
    • Financial Functions
    • Information Functions
    • Logical Functions
    • Lookup and Reference Functions
    • Math and Trig Functions
    • Statistical Functions
    • Text Functions
    • Web Functions
  • Excel VBA
  • Excel Video Tutorials
  • Formatting
  • Grouping
  • Others

Logical Functions

  • FALSE function: Description, Usage, Syntax, Examples and Explanation
  • SWITCH function: Description, Usage, Syntax, Examples and Explanation
  • IF with wildcards in Excel
  • Nested IF function example in Excel
  • IF function: Description, Usage, Syntax, Examples and Explanation

Date Time

  • Add workdays no weekends in Excel
  • Two ways to sum time over 30 minutes in Excel
  • How to get same date next month or previous month in Excel
  • Count day of week between dates in Excel
  • List holidays between two dates in Excel

Grouping

  • Group numbers at uneven intervals in Excel
  • Group numbers with VLOOKUP in Excel
  • Group times into unequal buckets in Excel
  • Running count group by n size in Excel
  • How to randomly assign data to groups in Excel

General

  • Spell Check in Excel
  • Count cells that contain errors in Excel
  • Excel Default Templates
  • How to calculate total from percentage in Excel
  • Customize Ribbon In Excel
© 2025 xlsoffice . All Right Reserved. | Teal Smiles | Abbreviations And Their Meaning