今天遇到了一个外贸公司做发票,要把阿拉伯数字转换成英文字符的需求,场景类似于银行填写取款单需要把数字写成大写的中文。
用Google搜了下,发现微软官方就有教程,教你如何用vbs制作一个SpellNumber的函数,直接调用。
实践了一下,发现微软官方给的代码里面有两处小bug,有两处换行连接字符“ _ “给误加进去了。如果直接复制粘贴,运行会报错。
我简单优化下,直接可用VBS代码如下:
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 = 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 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"
Case Else
Dollars = Dollars & ""
End Select
Select Case Cents
Case ""
Cents = ""
Case "One"
Cents = " and One Cent"
Case Else
Cents = " and " & Cents & " Cents"
End Select
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
注意:以上代码还修改了两处逻辑:
1、原来如果小数点后为0,则会转成英文“no cent”,我移除了设置,如果小数点后为0,什么都不显示;
2、原来整数位有dollars的提示,我也移除了,满足有些订单是其它货币的需求。
具体代码如何使用呢?
以本人使用的Mac OS + Office 365为例。
首先打开Excel的设置(command + ,),找到Ribbon & Toolbar标签:
选择All Tabs,找到Developer,插入到Main Tabs里面,save保存
在主界面,你会看到developer的tab,点击Visual Basic:
会打开一个新代码编辑窗口,右键点击project – VBAProject窗口里面空白处,insert → module:
在出现的代码窗口,把上面的代码粘贴进去:
可以关闭这个代码窗口,回到excel表格。此时已可用spellnumber函数自动转化数字:
微软的工具确实很强大,vbs也很完善。
Google Suite里面的action script使用Js来实现了微软vbs的功能。
二者是云上和本地的区别,看似一样,实则为不同时代的产品。
最近看了微软CEO萨蒂亚·纳德拉的《刷新 – 重新发现商业与未来》,有一点重新认识了微软。
书不错,推荐阅读。