Formula to Convert Numbers to Words

K

Kiley

What is the formula to convert numbers to words?

Example:

Number Words
568 Five Hundred Sixty Eight
 
E

EricG

Here is some VBA code to do what you want. Use the first function in the
cell where you want the number spelled out (=SpellNumber(A1), etc). I can't
remember where I found this code...

'Main Function
Function SpellNumber(ByVal MyNumber)
Dim Dollars, Cents, Temp
Dim DecimalPlace, Count, NegativeSign
ReDim Place(9) As String
Place(2) = " Thousand "
Place(3) = " Million "
Place(4) = " Billion "
Place(5) = " Trillion "
' String representation of amount.
MyNumber = Trim(Str(MyNumber))
' Position of decimal place 0 if none.
DecimalPlace = InStr(MyNumber, ".")
' Convert cents and set MyNumber to dollar amount.
If DecimalPlace > 0 Then
Cents = GetTens(Left(Mid(MyNumber, DecimalPlace + 1) & _
"00", 2))
MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))
End If
'
If (Left(MyNumber, 1) = "-") Then
MyNumber = Right(MyNumber, Len(MyNumber) - 1)
NegativeSign = "Negative "
Else
NegativeSign = ""
End If
Count = 1
Do While MyNumber <> ""
Temp = GetHundreds(Right(MyNumber, 3))
If Temp <> "" Then Dollars = Temp & Place(Count) & Dollars
If Len(MyNumber) > 3 Then
MyNumber = Left(MyNumber, Len(MyNumber) - 3)
Else
MyNumber = ""
End If
Count = Count + 1
Loop
Select Case Dollars
Case ""
Dollars = "No Dollars"
Case "One"
Dollars = "One Dollar"
Case Else
Dollars = Dollars & " Dollars"
End Select
Select Case Cents
Case ""
Cents = " and No Cents"
Case "One"
Cents = " and One Cent"
Case Else
Cents = " and " & Cents & " Cents"
End Select
Dollars = NegativeSign & Dollars
SpellNumber = Dollars & Cents
End Function

' Converts a number from 100-999 into text
Function GetHundreds(ByVal MyNumber)
Dim Result As String
If Val(MyNumber) = 0 Then Exit Function
MyNumber = Right("000" & MyNumber, 3)
' Convert the hundreds place.
If Mid(MyNumber, 1, 1) <> "0" Then
Result = GetDigit(Mid(MyNumber, 1, 1)) & " Hundred "
End If
' Convert the tens and ones place.
If Mid(MyNumber, 2, 1) <> "0" Then
Result = Result & GetTens(Mid(MyNumber, 2))
Else
Result = Result & GetDigit(Mid(MyNumber, 3))
End If
GetHundreds = Result
End Function

' Converts a number from 10 to 99 into text.
Function GetTens(TensText)
Dim Result As String
Result = "" ' Null out the temporary function value.
If Val(Left(TensText, 1)) = 1 Then ' If value between 10-19...
Select Case Val(TensText)
Case 10: Result = "Ten"
Case 11: Result = "Eleven"
Case 12: Result = "Twelve"
Case 13: Result = "Thirteen"
Case 14: Result = "Fourteen"
Case 15: Result = "Fifteen"
Case 16: Result = "Sixteen"
Case 17: Result = "Seventeen"
Case 18: Result = "Eighteen"
Case 19: Result = "Nineteen"
Case Else
End Select
Else ' If value between 20-99...
Select Case Val(Left(TensText, 1))
Case 2: Result = "Twenty "
Case 3: Result = "Thirty "
Case 4: Result = "Forty "
Case 5: Result = "Fifty "
Case 6: Result = "Sixty "
Case 7: Result = "Seventy "
Case 8: Result = "Eighty "
Case 9: Result = "Ninety "
Case Else
End Select
Result = Result & GetDigit _
(Right(TensText, 1)) ' Retrieve ones place.
End If
GetTens = Result
End Function

' Converts a number from 1 to 9 into text.
Function GetDigit(Digit)
Select Case Val(Digit)
Case 1: GetDigit = "One"
Case 2: GetDigit = "Two"
Case 3: GetDigit = "Three"
Case 4: GetDigit = "Four"
Case 5: GetDigit = "Five"
Case 6: GetDigit = "Six"
Case 7: GetDigit = "Seven"
Case 8: GetDigit = "Eight"
Case 9: GetDigit = "Nine"
Case Else: GetDigit = ""
End Select
End Function



Function GetOrdinalDates(theDate As Date, Optional theStyle As Integer) As
String
Dim daySuffix As String, theDateStr As String

If (IsMissing(theStyle)) Then
theStyle = 1
ElseIf (theStyle < 1 Or theStyle > 3) Then
theStyle = 1
End If
'
On Error GoTo errhandler
If Not IsDate(theDate) Then
GetOrdinalDates = "Oops!"
Exit Function
End If
' Determine date format.
Select Case Day(theDate)
Case 1, 21, 31
daySuffix = Day(theDate) & "st"
Case 2, 22
daySuffix = Day(theDate) & "nd"
Case 3, 23
daySuffix = Day(theDate) & "rd"
Case Else
daySuffix = Day(theDate) & "th"
End Select
' Use ONE of the following formats.
' Remove the remark(apostrophe) from the
' command lines that produce the desired format.
' -----------------------------------------------
' - Format example: 24th day of February, 1999
Select Case theStyle
Case 1
theDateStr = daySuffix & " day of " _
& Format$(theDate, "mmmm, yyyy")

' - Format example: February 24th, 1999
Case 2
theDateStr = Format$(theDate, "mmmm") & " " & _
daySuffix & Format$(theDate, ", yyyy")

' - Format example: Tuesday the 24th, 1999
Case 3
theDateStr = Format$(theDate, "dddd") & " the " & _
daySuffix & " day of " _
& Format$(theDate, "mmmm, yyyy")
End Select

GetOrdinalDates = theDateStr
Exit Function
'
errhandler:
GetOrdinalDates = "Oops!"
End Function

HTH,

Eric
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top