Consulting

Results 1 to 9 of 9

Thread: SpellNumber as per Currency Selection

  1. #1
    VBAX Regular
    Joined
    Jul 2011
    Posts
    66
    Location

    SpellNumber as per Currency Selection

    Hi All,

    This title sounds very familiar to many. I have a worksheet name Fax-Transmittal where I request payments for various vendors in various currencies. Currently I am using below function for SpellNumber which converts just numbers without currency, for example; 322,628.21 to Three Hundred Twenty Two Thousand Six Hundred Twenty Eight & 21/100:
    [VBA]
    Option Explicit

    'Main Function
    Function SpellNumber(ByVal MyNumber)
    Dim Dollars, 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 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 = 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
    Select Case Dollars
    Case ""
    Dollars = ""
    Case "One"
    Dollars = "One Dollar"
    Case Else
    Dollars = Dollars & " &"
    End Select
    Cents = Cents & "/100"

    SpellNumber = "" & 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
    [/VBA]

    Then I have one worksheet with currency names where in column "A" its all currency symbol and in column "B" I have their full name such as US$ = US Dollars, ZAR = Rands, GBP = Pounds, N$ = NamDollars, etc...

    Then I in fax transmittal sheet, I am using following formula to get my things done:

    ="Would you arrange for "&F33&" "&TEXT(G33,"#,##0.00_ ;[Red]-(#,##0.00)")&"("&Spellnumber(G33)&" "&VLOOKUP(F33,'Currency names'!A:B,2,0)&" Only) to be transferred to:"

    Where F33 is currency symbol & g33 is the numberical values.

    So my result looks like "Would you arrange for ZAR 322,628.21 (Three Hundred Twenty Two Thousand Six Hundred Twenty Eight & 21/100 Rands Only) to be transferred to:"

    I would request you all, if anyone can help me with private sub working with spellnumber instead of having currency name worksheet and vlookup formula.

    Please help.

  2. #2
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,728
    Location
    What's the difficulity with using the worksheet?

    No matter what you do, you'd need that Name and Symbol information someplace.

    It could hardcoded into a function, but it's easier to maintain as a data worksheet.

    Paul

  3. #3
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    You would have to have a lookup table somwehere, hard-coding it into a VBA array is a bad idea, so while you could do it, I cannot see the point.

    Maybe to keep it simple you could add four arguments to your SpellNumber function and call like so

    =Spellnumber(F33,G33,"Would you arrange for ", "to be transferred to:")

    [VBA] 'Main Function
    Function SpellNumber( _
    ByVal MyCurrency As String, _
    ByVal MyNumber As Variant, _
    MyPreText As String, _
    MyPostText As String)
    Dim MyOriginalNumber As Double
    Dim Dollars, Cents, Temp
    Dim DecimalPlace, Count
    ReDim Place(9) As String
    Place(2) = " Thousand "
    Place(3) = " Million "
    Place(4) = " Billion "
    Place(5) = " Trillion "

    MyOriginalNumber = MyNumber
    ' 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 = 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
    Select Case Dollars
    Case ""
    Dollars = ""
    Case "One"
    Dollars = "One Dollar"
    Case Else
    Dollars = Dollars & " &"
    End Select
    Cents = Cents & "/100"

    SpellNumber = MyPreText & MyCurrency & " " & Application.Text(MyOriginalNumber, "#,##0.00_ ;[Red]-(#,##0.00)") & _
    "(" & Dollars & " " & Cents & " " & _
    Application.VLookup(MyCurrency, Worksheets("Currency names").Range("A:B"), 2, False) & " only) " & _
    MyPostText
    End Function[/VBA]

    The lookup table could also be added as an argument to make it more flexible, less hard-coded, but I think like Paul that what you have is good enough.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  4. #4
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,728
    Location
    Another issue that may or may not be a problem is the formatting of numbers and currency and dates for different counteries.

    If you go to Control Panel, Regional and Language Options, Format tab

    US currency format is $123,456,789.00

    Different counteries use different decimal seperators, groupings, as well as just currency symbols, etc.

    You might need or want to add country-specific format strings to your VLookup sheet

    Paul
    Attached Images Attached Images

  5. #5
    VBAX Regular
    Joined
    Jul 2011
    Posts
    66
    Location
    Thank you guys,

    I will stick with what I have, I think this option wouldn't be done through vba.

  6. #6
    VBAX Regular
    Joined
    Jul 2011
    Posts
    66
    Location
    One more thing,

    When there is no cents, still my spell number gives out /100 Only as I set case for decimal as " Cents = Cents & "/100", could you guys please help me in this.

  7. #7
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [VBA]
    'Main Function
    Function SpellNumber(ByVal MyNumber)
    Dim Dollars, 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 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 = 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
    Select Case Dollars
    Case ""
    Dollars = ""
    Case "One"
    Dollars = "One Dollar"
    Case Else
    Dollars = Dollars
    End Select
    Cents = Cents

    SpellNumber = Dollars & IIf(Cents > 0, "& " & Cents & "/100", "")
    End Function[/VBA]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  8. #8
    VBAX Regular
    Joined
    Jul 2011
    Posts
    66
    Location

    Solved: SpellNumber as per Currency Selection

    Thanks a lot Mr. James.

  9. #9
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Quote Originally Posted by Shums
    Thanks a lot Mr. James.
    Not me, http://en.wikipedia.org/wiki/James_Thurber
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •