Excel populates bookmarks in Word, but I need Excel to "spell" a number!

Gordo24

New Member
Joined
Apr 19, 2011
Messages
43
Okay, I posted the code below before and got help on a different problem. I now have a new issue I need assistance with or at least confirm if it can be done. Excel is my data source and Word is is my template with bookmarks. The code below opens up my Word template from Excel and populates my bookarks with the applicable Excel data. I have one cell (in example below it's A7) in which I need Excel to convert 30 to Thirty (capital T is important). So for this one cell only, I need to "spell" the number. Can this be done?? Any help would be appreciated! Here is the code:

Sub createTemplate()
On Error GoTo errorHandler
Dim wdApp As Word.Application
Dim myDoc As Word.Document
Dim mywdRange As Word.Range
Dim CatD As Excel.Range
Dim CatB As Excel.Range

Set wdApp = New Word.Application
With wdApp
.Visible = True
.WindowState = wdWindowStateMaximize
End With
Set myDoc = wdApp.Documents.Add(Template:="C:\Test.doc")
Set CatD = Sheets("Sheet1").Range("A7")
Set CatB = Sheets("Sheet1").Range("A6")

With myDoc.Bookmarks
.Item("CatD").Range.InsertAfter CatD.Text
.Item("CatB").Range.InsertAfter CatB.Text
End With

errorHandler:
Set wdApp = Nothing
Set myDoc = Nothing
Set mywdRange = Nothing
End Sub
 
Kenneth, you got it! With your function plus the "Num2Words(CatD.Value2)" modification it works! Thanks a ton.
 
Upvote 0

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
I did a tweak on my macro to make it a bit better. IT still has a few issues but works for several scenarios.

Code:
Sub Test_Num2Words()
  Dim r As Range, tf As Boolean
  Set r = Range("A1")
  If InStr(r.NumberFormat, "%") > 0 Then tf = True
  If tf Then
    Range("A2").Value = Num2Words(r.Value * 100) & " Percent"
    Else: Range("A2").Value = Num2Words(r.Value)
  End If
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
    Debug.Print MyNumber - Fix(MyNumber)
    If sArray(i) = "point" And MyNumber Mod 1 = 0 Then sArray(i) = ""
  Next i
  ss = Join(sArray(), " ")
  ss = Trim(Replace(ss, "  ", " "))
  If Right(ss, 5) = "point" Then ss = Left(ss, Len(ss) - 5)
  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
 
Upvote 0
Ken,

You're right. Your code does not work with the decimals very well. Is there something in the code to simply remove the decimal portion? For example, if the result is 1,231.5, it would simply output One Thousand Two Hundred Thirty One?
 
Upvote 0
Kenneth, I removed a few lines from your code and was able to get it to drop the decimal portion of written out text.
 
Upvote 0

Forum statistics

Threads
1,225,155
Messages
6,183,214
Members
453,151
Latest member
Lizamaison

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