Option Explicit
Sub SplitData()
Dim c As Range, a As Long, b As Long
Dim MyH As String, MyK As String, MyS As String
Dim Sp, Sp2
Dim Hold As String
For Each c In Range("A1", Range("A" & Rows.Count).End(xlUp))
b = 0
On Error Resume Next
b = Application.WorksheetFunction.Find(",", c, 1)
On Error GoTo 0
If b = 0 Then
Sp = Split(c.Value, " ")
a = UBound(Sp)
c.Offset(, 1) = SpellNumber(Sp(a))
Else
Sp = Split(c.Value, " ")
Sp2 = Split(Sp(1), ",")
Hold = "": MyH = "": MyK = "": MyS = ""
For b = LBound(Sp2) To UBound(Sp2)
Select Case b
Case 0 'Lacs, MyS
MyS = Sp2(0)
Case 1 'Thousand, MyK
If Len(Sp2(1)) = 1 Then
MyK = "00" & Sp2(1)
ElseIf Len(Sp2(1)) = 2 Then
MyK = "0" & Sp2(1)
Else
MyK = Sp2(1)
End If
Case 2 'Hundred, MyH
If Len(Sp2(2)) = 1 Then
MyH = "00" & Sp2(2)
ElseIf Len(Sp2(2)) = 2 Then
MyH = "0" & Sp2(2)
Else
MyH = Sp2(2)
End If
End Select
Next b
Hold = Hold & MyS & MyK & MyH
c.Offset(, 1) = SpellNumber(Hold)
End If
Next c
End Sub
Function SpellNumber(ByVal MyNumber)
'
' http://support.microsoft.com/kb/213360
' =SpellNumber(32.50)
' =SpellNumber(A1)
'
Dim Dollars, Cents, Temp
Dim DecimalPlace, Count
ReDim Place(9) As String
Place(2) = " Thousand "
Place(3) = " Lacs " '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
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
SpellNumber = Dollars
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