Custom Cell Format for Feet (') & Inches (")

SteveT24

New Member
Joined
Apr 19, 2018
Messages
7
Good morning Mr. Excel Community,

I need help to create a custom cell value format to show my input (4 digit number) as "##'-##" (Ft'-In"). I've done some research on the rules/boundaries for creating custom cell formats within Excel & how to add text to a numerical value, but I have not been able to successfully add text (such as ##"'-"##""") in 2 separate locations within my cell value.

My goal is for this custom cell format to work similarly to the dimensions fields within Onscreen Take-off (OSTO), the primary software I use in my current position. Within OSTO, the dimensions are entered as 4 digits (first 2 digits as FEET, last 2 digits as inches) and the punctuation is added to create a dimensional output. For example...

0106 = 1'-6"
1109 = 11'-9"
2403 = 24'-3"
0610 = 6'-10"

Can this be achieved via a custom cell format? Or would it be necessary to have multiple columns (such as FEET & INCHES) with a 3rd column to concatenate the values with the desired punctuation/in the desired format?

Thanks in advance for any light you can shed on this.
 
Sorry for the late follow-up on this. Thank you all for your potential solutions, but I figured out another, simpler way to accomplish this but have run into new problems.

I've created a custom cell format to automatically convert my input into the desired format.

The custom format I've created is ##\'\-##" (though excel automatically changes the format to ##'-##").

INPUT - OUTPUT
1003 - 10'-03"
10003 - 100'-03"
100003 - 1000'-03"

..but here's my problem...
1212 - 12'-12"
76 - 00'-76"

Anything I can do to convert inches to feet whenever possible?
Desired Results:
1212 - 13'-00"
76 - 06'-04"
Give this formula a try...

=SUBSTITUTE(TEXT(IF(LEN(A1)<3,0,LEFT(A1,LEN(A1)-2))+RIGHT(A1,2)/12,"00""'-""00/12"),"/12","""")
 
Last edited:
Upvote 0

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Just as a suggestion, here’s an alternative way of converting the input, allowing potentially redundant output elements to be omitted, e.g. 1212 becomes 13’ rather than 13’-00”. This is not exactly in keeping with the originally requested output format – but it may be useful, as an editable user-defined function, for people wishing to experiment with different output formats.

The function is listed first, followed by the results it produces.

' ###########################################
Function ShowAsFeetAndInches(vstring)
' Patrick S. (PatrickOfLondon), 2019-09-18

' vstring should be a number,
' or a text string that can be
' understood as a number
q = IsNumeric(vstring)
If q = False Then
ShowAsFeetAndInches = vstring _
& " is not numerical in form."​
Exit Function​
End If​

' make sure the string has
' at least 3 characters: 2 for the inches
' and at least 1 for the feet
While Len(vstring) < 3
vstring = "0" & vstring​
Wend​

' assume the final 2 digits represent inches
inches = Right(vstring, 2)​
' assume the other, left-most digits represent feet
vlen = Len(vstring)
feet = Left(vstring, vlen - 2)​
' add any quantities of feet hidden in the inches
feet = feet + Int(inches / 12)​
' and then reduce inches to purely the inches content
inches = inches Mod 12​

' format the output elements. Vary as desired
If feet > 0 Then
feet = Format(feet, "#,0") & Chr(39)​
Else
feet = ""​
End If

If inches > 0 Then
inches = Format(inches, "#") & Chr(34)​
Else
inches = ""​
End If​
ShowAsFeetAndInches = Trim(feet & " " & inches)​

End Function
' ###########################################

[TABLE="width: 449"]
<tbody>[TR]
[TD]Source text[/TD]
[TD]Function result[/TD]
[TD]Contents of cell at left
(1003 is in A2)[/TD]
[/TR]
[TR]
[TD]1003[/TD]
[TD]10' 3"[/TD]
[TD]=ShowAsFeetAndInches(A2)[/TD]
[/TR]
[TR]
[TD]10003[/TD]
[TD]100' 3"[/TD]
[TD]=ShowAsFeetAndInches(A3)[/TD]
[/TR]
[TR]
[TD]100003[/TD]
[TD]1,000' 3"[/TD]
[TD]=ShowAsFeetAndInches(A4)[/TD]
[/TR]
[TR]
[TD]1212[/TD]
[TD]13'[/TD]
[TD]=ShowAsFeetAndInches(A5)[/TD]
[/TR]
[TR]
[TD]76[/TD]
[TD]6' 4"[/TD]
[TD]=ShowAsFeetAndInches(A6)[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]5"[/TD]
[TD]=ShowAsFeetAndInches(A7)[/TD]
[/TR]
[TR]
[TD]1234567[/TD]
[TD]12,350' 7"[/TD]
[TD]=ShowAsFeetAndInches(A8)[/TD]
[/TR]
[TR]
[TD]1234560[/TD]
[TD]12,350'[/TD]
[TD]=ShowAsFeetAndInches(A9)[/TD]
[/TR]
[TR]
[TD]0[/TD]
[TD][/TD]
[TD]=ShowAsFeetAndInches(A10)[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]7"[/TD]
[TD]=ShowAsFeetAndInches(A11)[/TD]
[/TR]
[TR]
[TD]Four foot eight[/TD]
[TD]Four foot eight is not numerical in form.[/TD]
[TD]=ShowAsFeetAndInches(A12)[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
Just as a suggestion, here’s an alternative way of converting the input, allowing potentially redundant output elements to be omitted, e.g. 1212 becomes 13’ rather than 13’-00”. This is not exactly in keeping with the originally requested output format – but it may be useful, as an editable user-defined function, for people wishing to experiment with different output formats.
Here is another, more compact way to write your function (it should produce the identical output as the function you posted)...
Code:
Function ShowAsFeetAndInches(S As String) As String
  Dim Feet As Long, Inches As Long
  [B][COLOR="#0000FF"]If Not S Like "*[!0-9]*" Then[/COLOR][/B]
    Feet = Int(S / 100)
    Inches = S Mod 100
    If Inches >= 12 Then
      Feet = Feet + Int(Inches / 12)
      Inches = Inches Mod 12
    End If
    ShowAsFeetAndInches = Trim(IIf(Feet = 0, "", Format(Feet, "#,###") & "'") & IIf(Inches = 0, "", " " & Inches & """"))
  Else
    ShowAsFeetAndInches = """" & S & """ is not numerical in form."
  End If
End Function

A note about the line of code I highlighted in blue... it tests to see if the text contained in the variable S is all digits or not (by the way, your function accepts floating point numbers and produces odd results with them). Using IsNumeric to "proof" that a text string is a valid number will not alway work the way one might think it should. From a previous post of mine...

I usually try and steer people away from using IsNumeric to "proof" supposedly numeric text. Consider this (also see note below):

Rich (BB code):
ReturnValue = IsNumeric("($1,23,,3.4,,,5,,E67$)")

Most people would not expect THAT to return True. IsNumeric has some "flaws" in what it considers a proper number and what most programmers are looking for.

I had a short tip published by Pinnacle Publishing in their Visual Basic Developer magazine that covered some of these flaws. Originally, the tip was free to view but is now viewable only by subscribers.. Basically, it said that IsNumeric returned True for things like -- currency symbols being located in front or in back of the number as shown in my example (also applies to plus, minus and blanks too); numbers surrounded by parentheses as shown in my example (some people use these to mark negative numbers); numbers containing any number of commas before a decimal point as shown in my example; numbers in scientific notation (a number followed by an upper or lower case "D" or "E", followed by a number equal to or less than 307 -- the maximum power of 10 in VB); and Octal/Hexadecimal numbers (&H for Hexadecimal, &O or just & in front of the number for Octal).

NOTE:
======
In the above example and in the referenced tip, I refer to $ signs and commas and dots -- these were meant to refer to your currency, thousands separator and decimal point symbols as defined in your local settings -- substitute your local regional symbols for these if appropriate.

As for your question about checking numbers, here are two functions that I have posted in the past for similar questions..... one is for digits only and the other is for "regular" numbers (the code is simple enough that it can be pulled from the function "housing" and used directly inside your own code):

Rich (BB code):
Function IsDigitsOnly(Value As String) As Boolean
    IsDigitsOnly = Len(Value) > 0 And Not Value Like "*[!0-9]*"
End Function

Function IsFloatingPoint(ByVal Value As String) As Boolean
    '   Leave the next statement out if you don't
    '   want to provide for plus/minus signs
    If Value Like "[+-]*" Then Value = Mid$(Value, 2)
    IsFloatingPoint = Not Value Like "*[!0-9.]*" And Not Value Like "*.*.*" And Len(Value) > 0 And Value <> "."
End Function

Here are revisions to the above functions that deal with the local settings for decimal points (and thousand's separators) that are different than used in the US (this code works in the US too, of course).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function

I'm not as concerned by the rejection of entries that include one or more thousand's separators, but we can handle this if we don't insist on the thousand's separator being located in the correct positions (in other words, we'll allow the user to include them for their own purposes... we'll just tolerate their presence).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  Dim TS As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Get local setting for thousand's separator
  '   and eliminate them. Remove the next two lines
  '   if you don't want your users being able to
  '   type in the thousands separator at all.
  TS = Mid$(Format$(1000, "#,###"), 2, 1)
  Value = Replace$(Value, TS, "")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function
 
Last edited:
Upvote 0
Here is another, more compact way to write your function (it should produce the identical output as the function you posted)...

Thank you for that, Rick -- very compact and efficient. It does indeed produce the same results, at least in the examples I showed in my post -- with the added bonus of quotes around any non-numeric string it rejects!

I'd be interested, just out of curiosity, if you could give one or two examples of the floating-point numbers that produced the odd results you mentioned.

Thanks again for your interest and collaboration.
 
Upvote 0
Try this custom number format for the above issue......
#0 "'"- 00 "'''"
for multiplication the format you can use this formula in Cell A5
=PRODUCT(A1,DOLLARDE(A2,12),DOLLARDE(A3,12),DOLLARDE(A4,12))
 
Upvote 0
I just wanted to tack on here a simple formula that less experienced users can use as well. If you are wanting an excel formula to convert it for you, you can also use the formula I wrote up below. Please note, you will need to change "I2" to whatever cell you are wanting it to convert. Additionally, to make it the most useful I knew how I added a function to round to the inches to the nearest whole inch, but you can remove it if you need your measurements more exact:

=CONCATENATE(INT(I2),CHAR(39)," - ",ROUND((I2-INT(I2))*12,0),CHAR(34))

Now it converts it for you:
1661535045500.png

Please note, I used CONCATENATE instead of the current CONCAT simply for compatibility with older versions as well.
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,209
Members
453,022
Latest member
RobertV1609

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