<<Convert Excel Spreadsheets to Web Pages | Trading Software That Operates Within Excel | Convert Excel, Access & Other Databases | Merge Excel Files>>
Ozgrid, Experts in Microsoft Excel Spreadsheets

Excel: Convert Currency Number to Words/Text

TRY OUT: Smart-VBA | Code-VBA | Analyzer-XL | Downloader-XL | Trader-XL| More Free Downloads.. Best Value: Finance Templates Bundle

Back to: Excel Custom Function/Formulas . Got any Excel/VBA Questions? Free Excel Help

See Also: Convert Numbers to Words/Text

Here is a very popular bit of code from Microsoft that will convert any currency amount in a cell to English words. All code and text from below here is the work of Microsoft.

Summary
This article shows you how to create a sample, user-defined function named ConvertCurrencyToEnglish() to convert a numeric value to an English word representation. For example, the function will return the following words for the number 1234.56: One Thousand Two Hundred Thirty Four Dollars And Fifty Six Cents

The Function Wizard can also be used to enter a custom function in a worksheet. To use the Function Wizard, follow these steps:

1. Click the Function Wizard button, and select User Defined under Function Category.
2. Select ConvertCurrencyToEnglish, and enter your number or cell reference.
3. Click Finish

To Create the Sample Functions

1. Insert a module sheet into a workbook. To do this in Microsoft Excel 97 or Microsoft Excel 98, point to Macro on the Tools menu, and then click Visual Basic Editor. In the Visual Basic Editor, click Module on the Insert menu. In Microsoft Excel 5.0 or 7.0, point to Macro on the Insert menu and click Module.

2. Type the following code into the module sheet.

Function ConvertCurrencyToEnglish (ByVal MyNumber)Dim Temp         Dim Dollars, Cents         Dim DecimalPlace, Count         ReDim Place(9) As String         Place(2) = " Thousand "         Place(3) = " Million "         Place(4) = " Billion "         Place(5) = " Trillion "         ' Convert MyNumber to a string, trimming extra spaces.         MyNumber = Trim(Str(MyNumber))         ' Find decimal place.         DecimalPlace = InStr(MyNumber, ".")         ' If we find decimal place...         If DecimalPlace > 0 Then            ' Convert cents            Temp = Left(Mid(MyNumber, DecimalPlace + 1) & "00", 2)            Cents = ConvertTens(Temp)            ' Strip off cents from remainder to convert.            MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))         End If         Count = 1         Do While MyNumber <> ""            ' Convert last 3 digits of MyNumber to English dollars.            Temp = ConvertHundreds(Right(MyNumber, 3))            If Temp <> "" Then Dollars = Temp & Place(Count) & Dollars            If Len(MyNumber) > 3 Then               ' Remove last 3 converted digits from MyNumber.               MyNumber = Left(MyNumber, Len(MyNumber) - 3)            Else               MyNumber = ""            End If            Count = Count + 1         Loop         ' Clean up dollars.         Select Case Dollars            Case ""               Dollars = "No Dollars"            Case "One"               Dollars = "One Dollar"            Case Else               Dollars = Dollars & " Dollars"         End Select         ' Clean up cents.         Select Case Cents            Case ""               Cents = " And No Cents"            Case "One"               Cents = " And One Cent"            Case Else               Cents = " And " & Cents & " Cents"         End Select         ConvertCurrencyToEnglish = Dollars & CentsEnd FunctionPrivate Function ConvertHundreds (ByVal MyNumber)Dim Result As String         ' Exit if there is nothing to convert.         If Val(MyNumber) = 0 Then Exit Function         ' Append leading zeros to number.         MyNumber = Right("000" & MyNumber, 3)         ' Do we have a hundreds place digit to convert?         If Left(MyNumber, 1) <> "0" Then            Result = ConvertDigit(Left(MyNumber, 1)) & " Hundred "         End If         ' Do we have a tens place digit to convert?         If Mid(MyNumber, 2, 1) <> "0" Then            Result = Result & ConvertTens(Mid(MyNumber, 2))         Else            ' If not, then convert the ones place digit.            Result = Result & ConvertDigit(Mid(MyNumber, 3))         End If         ConvertHundreds = Trim(Result)End FunctionPrivate Function ConvertTens (ByVal MyTens)Dim Result As String         ' Is value between 10 and 19?         If Val(Left(MyTens, 1)) = 1 Then            Select Case Val(MyTens)               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            ' .. otherwise it's between 20 and 99.            Select Case Val(Left(MyTens, 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            ' Convert ones place digit.            Result = Result & ConvertDigit(Right(MyTens, 1))         End If         ConvertTens = ResultEnd FunctionPrivate Function ConvertDigit (ByVal MyDigit)Select Case Val(MyDigit)            Case 1: ConvertDigit = "One"            Case 2: ConvertDigit = "Two"            Case 3: ConvertDigit = "Three"            Case 4: ConvertDigit = "Four"            Case 5: ConvertDigit = "Five"            Case 6: ConvertDigit = "Six"            Case 7: ConvertDigit = "Seven"            Case 8: ConvertDigit = "Eight"            Case 9: ConvertDigit = "Nine"            Case Else: ConvertDigit = ""         End SelectEnd Function

See Also: Excel Duplication Manager Add-in |Excel Number Manager Add-in | Excel Text Manager Add-in |Excel Named Range Add-in Manager |Excel OzGrid Plus Add-in |Excel Time Sheet | Excel Time Wage and Pay book

Excel Dashboard Reports & Excel Dashboard Charts 50% Off Become an ExcelUser Affiliate & Earn Money

Special! Free Choice of Complete Excel Training Course OR Excel Add-ins Collection on all purchases totaling over $64.00. ALLpurchases totaling over $150.00 gets you BOTH! Purchases MUST be made via this site. Send payment proof to [email protected] 31 days after purchase date.



Instant Download and Money Back Guarantee on Most Software

Try out:Analyzer XL |Downloader XL |Smart VBA |Trader XL Pro (best value) |ConsoXL | MergeXL | O2OLAP for Excel | MORE>>

Excel Trader PackageTechnical Analysis in Excel With $139.00 of FREE software!

Microsoft � and Microsoft Excel � are registered trademarks of Microsoft Corporation. OzGrid is in no way associated with Microsoft

Some of our more popular products are below...
Convert Excel Spreadsheets To Webpages | Trading In Excel | Construction Estimators | Finance Templates & Add-ins Bundle | Code-VBA | Smart-VBA | Print-VBA | Excel Data Manipulation & Analysis | Convert MS Office Applications To...... | Analyzer Excel | Downloader Excel | MSSQL Migration Toolkit | Monte Carlo Add-in | Excel Costing Templates