Spellnumber function

tallboy

New Member
Joined
Mar 1, 2022
Messages
4
Office Version
  1. 365
  2. 2021
Help very new to VBA and using microsofts SpellNumber function getting a Compile error: Argument not optional
on this section highlighted in bold in the code

End Select

Result = Result & GetDigit _

(Right(TensText, 1)) ' Retrieve ones place.





VBA Code:
Option Explicit

'Main Function

Function SpellNumber(ByVal MyNumber)

Dim Pounds, Pence, Temp

Dim DecimalPlace, Count

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 pence and set MyNumber to pound amount.

If DecimalPlace > 0 Then

Pence = 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 Pounds = Temp & Place(Count) & Pounds

If Len(MyNumber) > 3 Then

MyNumber = Left(MyNumber, Len(MyNumber) - 3)

Else

MyNumber = ""

End If

Count = Count + 1

Loop

Select Case Pounds

Case ""

Pounds = "No Pounds"

Case "One"

Pounds = "One Pound"

Case Else

Pounds = Pounds & " Pounds"

End Select

Select Case Pence

Case ""

Pence = " and No Pence"

Case "One"

Pence = " and One Cent"

Case Else

Pence = " and " & Pence & " Pence"

End Select

SpellNumber = Pounds & Pence

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

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Welcome to the Board!

I don't think it likes you splitting up the line in a middle of a function. You usually only split lines between arguments or pieces of a concatenation.

Try changing that problem line to this:
VBA Code:
Result = Result & GetDigit(Right(TensText, 1)) ' Retrieve ones place.
 
Upvote 0
Solution
You are welcome.
Glad I was able to help!
 
Upvote 0
Further issue just cropped up with this. when number is rounded up in the formulas result the text version as it only goes to 2 dp does not round up. is there a modification to the VBA code that can address this. working around at the moment using round down so number and text match.

£??,???.26 written as '... and twenty five pence' because the formula result is £??,???.258
 
Upvote 0
Are the values you are trying to run this against entered as numbers or strings?
 
Upvote 0
If yout want to round it to 2 decimal places, update this section of your SpellNumber function:
VBA Code:
' String representation of amount.
    MyNumber = Trim(Str(MyNumber))
with this:
VBA Code:
' String representation of amount.
    MyNumber = Round(MyNumber, 2)
    MyNumber = Trim(Str(MyNumber))
 
Upvote 0

Forum statistics

Threads
1,214,904
Messages
6,122,169
Members
449,070
Latest member
webster33

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