spell out numbers (part II)


Posted by Amy Wheeler on September 17, 2001 9:43 AM

I saw the responses regarding this question, and when I when to the other hits, it changed a number to text (but using currency) i.e. 15 became fifteen dollars and zero cents.

What I am looking for is "fifteen" excluding the dollars and cents.

Thanks!
Amy

Posted by Eric on September 17, 2001 11:57 AM

This one has a check box for with or without the monetary units

http://geocities.com/aaronblood/xl_files/vba/num_2_text.zip
otherwise you could strip it with formula like
=LEFT(B2,LEN(B2)-20)
if the monetary result is in B2.

Posted by Barrie Davidson on September 17, 2001 12:27 PM

Amy, you could try out this User-Defined Function (courtesy of Alan Barasch's web site - http://www.barasch.com/excel/numb2words.htm - with some changes made by myself).

Option Explicit

'****************' Main Function *'****************
Function SpellNumber_NO_DOLLARS(ByVal MyNumber)
Dim Dollars, Cents, Temp
Dim DecimalPlace, Count, Rightofdecimal
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
Temp = Mid(MyNumber, DecimalPlace + 1)
Temp = Len(Temp) - Len(CStr(CDbl(Temp)))
For Count = 1 To Temp
Cents = Cents & " Zero"
Next Count
Rightofdecimal = CStr(CDbl(Mid(MyNumber, DecimalPlace + 1)))
Count = 1
Temp = ""
Do Until Count > Len(Rightofdecimal)
Temp = Temp & " " & GetDigit(Mid(Rightofdecimal, Count, 1))
Count = Count + 1
Loop
Cents = Cents & Temp
Cents = Cents & " " & GetDigit(CStr(CDbl(Mid(MyNumber, DecimalPlace + 1))))
MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))
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 = "Zero"
Case "One"
Dollars = "One"
Case Else
Dollars = Dollars & " Point"
End Select
Select Case Cents
Case ""
Cents = " zero"
Case "One"
Cents = " one"
Case Else
Cents = Cents
End Select
SpellNumber_NO_DOLLARS = 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


Regards,
BarrieBarrie Davidson

Posted by Barrie Davidson on September 17, 2001 2:22 PM

Change that function to:

'****************' Main Function *'****************
Function SpellNumber_NO_DOLLARS(ByVal MyNumber)
Dim Dollars, Cents, Temp
Dim DecimalPlace, Count, Rightofdecimal
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
Temp = Mid(MyNumber, DecimalPlace + 1)
Temp = Len(Temp) - Len(CStr(CDbl(Temp)))
For Count = 1 To Temp
Cents = Cents & " Zero"
Next Count
Rightofdecimal = CStr(CDbl(Mid(MyNumber, DecimalPlace + 1)))
Count = 1
Temp = ""
Do Until Count > Len(Rightofdecimal)
Temp = Temp & " " & GetDigit(Mid(Rightofdecimal, Count, 1))
Count = Count + 1
Loop
Cents = Cents & Temp
Cents = Cents & " " & GetDigit(CStr(CDbl(Mid(MyNumber, DecimalPlace + 1))))
MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))
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 = "Zero"
Case "One"
Dollars = "One"
Case Else
Dollars = Dollars & " Point"
End Select
Select Case Cents
Case ""
Cents = " zero"
Case "One"
Cents = " one"
Case Else
Cents = Cents
End Select
SpellNumber_NO_DOLLARS = 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 0: GetDigit = "Zero"
Case Else: GetDigit = ""
End Select
End Function


Regards,
Barrie
Barrie Davidson

Posted by Barrie Davidson on September 17, 2001 2:30 PM

Ignore my two postings below (found some errors).


Amy, try this (again (courtesy of Alan Barasch's web site - http://www.barasch.com/excel/numb2words.htm).

Option Explicit
'****************' Main Function *'****************
Function SpellNumber_NO_DOLLARS(ByVal MyNumber)
Dim Dollars, Cents, Temp
Dim DecimalPlace, Count, Rightofdecimal
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
Temp = Mid(MyNumber, DecimalPlace + 1)
Temp = Len(Temp) - Len(CStr(CDbl(Temp)))
For Count = 1 To Temp
Cents = Cents & " Zero"
Next Count
Rightofdecimal = CStr(CDbl(Mid(MyNumber, DecimalPlace + 1)))
Count = 1
Temp = ""
Do Until Count > Len(Rightofdecimal)
Temp = Temp & " " & GetDigit(Mid(Rightofdecimal, Count, 1))
Count = Count + 1
Loop
Cents = Cents & Temp
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 = "Zero"
Case "One"
Dollars = "One"
Case Else
Dollars = Dollars & " Point"
End Select
Select Case Cents
Case ""
Cents = " zero"
Case "One"
Cents = " one"
Case Else
Cents = Cents
End Select
SpellNumber_NO_DOLLARS = 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 0: GetDigit = "Zero"
Case Else: GetDigit = ""
End Select
End Function

Barrie Davidson



Posted by Barrie Davidson on September 17, 2001 2:38 PM

One more change (I think this is it!!)

Amy, insert

MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))

right after

Cents = Cents & Temp
End If

Sorry for the problems (I really shouldn't rush).

Barrie