工作中我们经常遇到在财务报表、合同签定、付款时需要填写大写的人民币金额,利用输入法写大写的话非常麻烦,并且容易出错。 方案1:excel本身有简单的处理方法,如:设置单元格格式“数字"-“特殊”-“中文大写数字”,这种方式对于带小数点的数字就不那么友好了,看123.567显示为壹佰贰拾叁.伍陆柒,元角分等单位无法显示出来,并且无法复制大写的金额到其他地方使用。
 方案2(推荐):利用Text、SUBSTITUTE等函数组合,公式为 =SUBSTITUTE(SUBSTITUTE(IF(ROUND(A1,2),TEXT(A1,";负")&TEXT(INT(ABS(A1)+0.5%),"[dbnum2]G/通用格式圆;;")&TEXT(RIGHT(TEXT(A1,".00"),2),"[dbnum2]0角0分;;整"),),"零角",IF(A1^2<1,,"零")),"零分","整"),A1单元格为你要转换的阿拉伯数字。
-123.016 |
负壹佰贰拾叁圆零贰分 |
=SUBSTITUTE(SUBSTITUTE(IF(ROUND(A1,2),TEXT(A1,";负")&TEXT(INT(ABS(A1)+0.5%), "[dbnum2]G/通用格式圆;;")&TEXT(RIGHT(TEXT(A1,".00"),2),"[dbnum2]0角0分;;整"),),"零角",IF(A1^2<1,,"零")),"零分","整") |
900 |
玖佰圆整 |
=SUBSTITUTE(SUBSTITUTE(IF(ROUND(A2,2),TEXT(A2,";负")&TEXT(INT(ABS(A2)+0.5%), "[dbnum2]G/通用格式圆;;")&TEXT(RIGHT(TEXT(A2,".00"),2),"[dbnum2]0角0分;;整"),),"零角",IF(A2^2<1,,"零")),"零分","整") |
800 |
捌佰圆整 |
=SUBSTITUTE(SUBSTITUTE(IF(ROUND(A3,2),TEXT(A3,";负")&TEXT(INT(ABS(A3)+0.5%), "[dbnum2]G/通用格式圆;;")&TEXT(RIGHT(TEXT(A3,".00"),2),"[dbnum2]0角0分;;整"),),"零角",IF(A3^2<1,,"零")),"零分","整") |
1500000 |
壹佰伍拾万圆整 |
=SUBSTITUTE(SUBSTITUTE(IF(ROUND(A4,2),TEXT(A4,";负")&TEXT(INT(ABS(A4)+0.5%), "[dbnum2]G/通用格式圆;;")&TEXT(RIGHT(TEXT(A4,".00"),2),"[dbnum2]0角0分;;整"),),"零角",IF(A4^2<1,,"零")),"零分","整") |
1589816.245 |
壹佰伍拾捌万玖仟捌佰壹拾陆圆贰角伍分 |
=SUBSTITUTE(SUBSTITUTE(IF(ROUND(A5,2),TEXT(A5,";负")&TEXT(INT(ABS(A5)+0.5%), "[dbnum2]G/通用格式圆;;")&TEXT(RIGHT(TEXT(A5,".00"),2),"[dbnum2]0角0分;;整"),),"零角",IF(A5^2<1,,"零")),"零分","整") |
900001234 |
玖亿壹仟贰佰叁拾肆圆整 |
=SUBSTITUTE(SUBSTITUTE(IF(ROUND(A6,2),TEXT(A6,";负")&TEXT(INT(ABS(A6)+0.5%), "[dbnum2]G/通用格式圆;;")&TEXT(RIGHT(TEXT(A6,".00"),2),"[dbnum2]0角0分;;整"),),"零角",IF(A6^2<1,,"零")),"零分","整") |
这种方法操作起来非常简单,设置好一个单元格后,只需往下拉就可以连续使用。您还可以“复制"-“选择性粘贴”-“数值”到其他单元格使用,是不是很方便。 |