Skip to content

数字英文转换

严格意义上来讲,Excel 当然不能归为编辑器这一类工具,但是考虑到外贸从业人士会经常使用 Excel 中的表格自动计算功能,来制作产品报价单或商业发票等文件,这基本上是将 Excel 当做 Word 使用,就姑且将之归类到编辑器吧。

本文主要记录,通过 Excel 中内置的 VBA 实现从数字到英文的转换,主要适用于商业发票的制作。

  1. 快捷键 Alt + F11 打开 VBA 编辑器
  2. 插入一个新模块
  3. 将 VBA 脚本复制粘贴至 Module1
  4. 将 Excel 文件另存,以 .xlsm 为后缀

在保存了脚本的 Excel 文件内的某个单元格使用自动转换功能时,只需简单地调用定义好的函数 =AmountToWords(K33, "US Dollars", "Cents") 即可,可以传入 3 个参数:

  • 引用数字的位置
  • 货币
  • 单位
vba
Option Explicit
' VBA Function to Convert Number to Word in Excel
Function NumToWords(ByVal MyNumber, Optional isProper As Boolean = False) As String
    Dim Units As String, SubUnits As String, TempStr As String
    Dim DecimalPlace As Integer, Count As Integer
    Dim Place(9) As String

    Place(2) = " Thousand "
    Place(3) = " Million "
    Place(4) = " Billion "
    Place(5) = " Trillion "

    ' Check if the input is empty or not a number
    If IsEmpty(MyNumber) Or Not IsNumeric(MyNumber) Then
        NumToWords = ""
        Exit Function
    End If

    ' Convert MyNumber to string and trim white space
    MyNumber = Trim(Str(MyNumber))

    ' Handle Zero Case
    If Val(MyNumber) = 0 Then
        NumToWords = "Zero"
        Exit Function
    End If

    ' Find position of decimal place (0 if none)
    DecimalPlace = InStr(MyNumber, ".")

    ' Convert Decimal Part
    If DecimalPlace > 0 Then
        SubUnits = GetDecimalWords(Mid(MyNumber, DecimalPlace + 1), isProper)
        MyNumber = Trim(Left(MyNumber, DecimalPlace - 1))
    End If

    ' Process Integer Part
    Count = 1
    Do While MyNumber <> ""
        TempStr = GetHundreds(Right(MyNumber, 3))
        If TempStr <> "" Then Units = TempStr & Place(Count) & Units
        If Len(MyNumber) > 3 Then
            MyNumber = Left(MyNumber, Len(MyNumber) - 3)
        Else
            MyNumber = ""
        End If
        Count = Count + 1
    Loop

    ' Combine Integer and Decimal Parts
    If SubUnits = "" Then
        NumToWords = Application.Trim(Units)
    Else
        NumToWords = Application.Trim(Units & " Point " & SubUnits)
    End If
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 Hundreds Place
    If Mid(MyNumber, 1, 1) <> "0" Then
        Result = GetDigit(Mid(MyNumber, 1, 1)) & " Hundred "
        ' Add "and" if there are tens or ones
        If Mid(MyNumber, 2, 2) <> "00" Then
            Result = Result & " and "
        Else
            Result = Result & " "
        End If
    End If

    ' Convert 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 = ""

    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"
        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"
        End Select
        ' Add hyphen between tens and ones
        If Right(TensText, 1) <> "0" Then
            Result = Result & "-" & GetDigit(Right(TensText, 1))
        End If
    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

' Converts Decimal Digits to Words
Function GetDecimalWords(DecimalPart As String, isProper As Boolean) As String
    Dim i As Integer, DecWord As String

    If isProper Then
        ' Proper: 25.57 ? "Twenty Five Point Five Seven"
        For i = 1 To Len(DecimalPart)
            If i > 1 Then DecWord = DecWord & " "
            DecWord = DecWord & GetDigit(Mid(DecimalPart, i, 1))
        Next i
    Else
        ' Default: 25.57 ? "Twenty Five Point Fifty Seven"
        DecWord = GetTens(Left(DecimalPart & "00", 2))
    End If

    GetDecimalWords = DecWord
End Function


Function AmountToWords(ByVal MyNumber, ByVal strCurrency As String, ByVal strUnits As String) As String
    Dim IntegerPart As String, DecimalPart As String
    Dim DecimalPlace As Integer

    ' Check if the input is empty or not a number
    If IsEmpty(MyNumber) Or Not IsNumeric(MyNumber) Then
        AmountToWords = ""
        Exit Function
    End If

    ' Convert MyNumber to string and trim white space
    MyNumber = Trim(Str(MyNumber))

    ' Find position of decimal place (0 if none)
    DecimalPlace = InStr(MyNumber, ".")

    ' Get Integer and Decimal Parts
    If DecimalPlace > 0 Then
        IntegerPart = Trim(Left(MyNumber, DecimalPlace - 1))
        DecimalPart = Right(MyNumber, Len(MyNumber) - DecimalPlace)
    Else
        IntegerPart = MyNumber
        DecimalPart = ""
    End If

    ' Initialize with "Total Say "
    AmountToWords = "Total Say "

    ' Convert Integer Part to words if not empty or zero
    If IntegerPart <> "" And Val(IntegerPart) > 0 Then
        AmountToWords = AmountToWords & NumToWords(IntegerPart) & " " & strCurrency
    End If

    ' Convert Decimal Part to words if not empty or zero
    If DecimalPart <> "" And Val(DecimalPart) > 0 Then
        If IntegerPart = "" Or Val(IntegerPart) = 0 Then
            AmountToWords = AmountToWords & NumToWords(Left(DecimalPart & "00", 2)) & " " & strUnits
        Else
            AmountToWords = AmountToWords & " and " & NumToWords(Left(DecimalPart & "00", 2)) & " " & strUnits
        End If
    End If
End Function
最近更新