Sub Test_Num2Words()
MsgBox Num2Words(1), , "1"
MsgBox Num2Words(1, True), , "1 in currency"
MsgBox Num2Words(1000.01), , "1000.01"
MsgBox Num2Words(1000.01, True), , "1000.01 in currency"
End Sub
'bulk of code similar to http://support.microsoft.com/kb/213360
'Currency=True to show dollars and cents
Function Num2Words(MyNumber As Double, Optional bCurrency As Boolean = False) As String
Dim Dollars As String, Cents As String
Dim Place(1 To 9) As String, i As Integer
Dim sNumber As String, DecimalPlace As Long
Dim Count As Long, Temp As String
Dim s As String, ss As String, sArray() As String
Dim r() As Variant, x As Variant
Dollars = ""
Cents = ""
For i = 1 To 9
Place(i) = ""
Next i
Place(2) = " Thousand "
Place(3) = " Million "
Place(4) = " Billion "
Place(5) = " Trillion "
sNumber = CStr(MyNumber)
' Position of decimal place 0 if none.
DecimalPlace = InStr(sNumber, ".") 'Change if decimal not "."
' Convert cents and set sNumber to dollar amount.
If DecimalPlace > 0 Then
Cents = GetTens(Left(Mid(sNumber, DecimalPlace + 1) & "00", 2))
sNumber = Trim(Left(sNumber, DecimalPlace - 1))
End If
Count = 1
While sNumber <> ""
Temp = GetHundreds(Right(sNumber, 3))
If Temp <> "" Then Dollars = Temp + Place(Count) & Dollars
If Len(sNumber) > 3 Then
sNumber = Left(sNumber, Len(sNumber) - 3)
Else
sNumber = ""
End If
Count = Count + 1
Wend
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
If bCurrency = True Then
Num2Words = Dollars & Cents
Exit Function
End If
s = Dollars + Cents
r() = Array("One Cent", "Cent", "Cents", "Dollar", "Dollars", "No")
sArray() = Split(s, " ")
For i = 1 To UBound(sArray)
For Each x In r()
If sArray(i) = x Then sArray(i) = ""
Next x
If sArray(i) = "and" Then sArray(i) = "point"
'Trim point trailer if no decimal numbers
If sArray(i) = "point" And MyNumber - Fix(MyNumber) = 0 Then sArray(i) = ""
Next i
ss = Join(sArray(), " ")
Debug.Print ss
ss = Replace(ss, " ", " ")
Num2Words = ss
End Function
' Converts a number from 100-999 into text
Function GetHundreds(MyNumber As String) As String
Dim Result As String
Result = ""
If Val(MyNumber) = 0 Then
GetHundreds = ""
Exit Function
End If
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 As String) As String
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
GetDigit = GetDigit
End Function