Add numerical in convert number to words

shunka8059

New Member
Joined
Aug 9, 2013
Messages
7
Hi,

I already had the VBA for converting invoice currency into words. Because I had to do something similar in packing list, I used the same VBA code and did some adjustment. The problem came after that. I need to add the numerical number within those words. Could anyone help me adjust the code?

So for a cell with 213, it should be:

TWO HUNDRED THIRTEEN (213) CARTONS ONLY

but instead, I get this:

TWO HUNDRED THIRTEEN () CARTONS ONLY


I didn't remove cents and decimals, since I don't know which part to remove without affecting the others. Although this wont' affect me, but it would be a greate help to remove them too.

Thanks in advance.


Code:
Option Explicit'Main Function
Function SpellCarton(ByVal MyNumber)
    Dim Cartons, Cents, Temp
    Dim DecimalPlace, Count
    ReDim Place(9) As String
    Place(2) = " THOUSAND "
    Place(3) = " MILLION "
    Place(4) = " BILLION "
    Place(5) = " TRILLION "
    ' String representation of quantity.
    MyNumber = Trim(Str(MyNumber))
    ' Position of decimal place 0 if none.
    DecimalPlace = InStr(MyNumber, ".")
    ' Convert cents and set MyNumber to carton quantity.
    If DecimalPlace > 0 Then
        Cents = GetTens(Left(Mid(MyNumber, DecimalPlace + 1) & _
                  "00", 2))
        MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))
    End If
    Count = 1
    Do While MyNumber <> ""
        Temp = GetHundreds(Right(MyNumber, 3))
        If Temp <> "" Then Cartons = Temp & Place(Count) & Cartons
        If Len(MyNumber) > 3 Then
            MyNumber = Left(MyNumber, Len(MyNumber) - 3)
        Else
            MyNumber = ""
        End If
        Count = Count + 1
    Loop
    Select Case Cartons
        Case ""
            Cartons = "NO CARTON"
        Case "ONE"
            Cartons = "ONE CARTON (1) ONLY"
        Case Else
            Cartons = Cartons & " (" & [B][COLOR=#ff0000]Val(MyNumber)[/COLOR][/B] & ")" & " CARTONS ONLY"
    End Select
    SpellCarton = Cartons
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
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
Make the changes highlighted below. There is also no need to convert the number to a string (which I took out).

Function SpellCarton(ByVal MyNumber)
Dim Cartons, Cents, Temp
Dim DecimalPlace, Count
Dim holdNumber As Long
holdNumber = MyNumber

ReDim Place(9) As String
Place(2) = " THOUSAND "
Place(3) = " MILLION "
Place(4) = " BILLION "
Place(5) = " TRILLION "
' Position of decimal place 0 if none.
DecimalPlace = InStr(MyNumber, ".")
' Convert cents and set MyNumber to carton quantity.
If DecimalPlace > 0 Then
Cents = GetTens(Left(Mid(MyNumber, DecimalPlace + 1) & _
"00", 2))
MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))
End If
Count = 1
Do While MyNumber <> ""
Temp = GetHundreds(Right(MyNumber, 3))
If Temp <> "" Then Cartons = Temp & Place(Count) & Cartons
If Len(MyNumber) > 3 Then
MyNumber = Left(MyNumber, Len(MyNumber) - 3)
Else
MyNumber = ""
End If
Count = Count + 1
Loop
Select Case Cartons
Case ""
Cartons = "NO CARTON"
Case "ONE"
Cartons = "ONE CARTON (1) ONLY"
Case Else
Cartons = Cartons & " (" & holdNumber & ")" & " CARTONS ONLY"
End Select
SpellCarton = Cartons
End Function
 
Upvote 0

Forum statistics

Threads
1,214,611
Messages
6,120,510
Members
448,967
Latest member
screechyboy79

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