Plz help me out !!!

arvind

New Member
Joined
Jul 22, 2009
Messages
20
Hi, all

I came 2 know from 1 of my friend tht this is the best forum abt excel & surely it looks like. Thanks for making this site for people like me who r born baby in excel.

Well friends I need 2 convet my currency (India) numerics 2 text, for example
Rs. 2,10,500 to Two Lacs Ten Thousand and Five Hundred.
I need this for my receipts and i'm not getting any clue so far. Plz can anyone help me.
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Try this UDF - I got this a while back from a Microsoft KB article. You'll have to convert dollars and cents to your equivalent terms.

Code:
Public Function ConvertNumberToEnglish(ByVal MyNumber) As String
    Dim temp
    Dim Dollars As String, Cents As String
    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.
    
    ' Clean up cents.
    Select Case Cents
       Case ""
          Cents = ""
       Case "One"
          Cents = " And One hundredth"
       Case Else
          Cents = " And " & Cents & " hundredths"
    End Select
    
    ConvertNumberToEnglish = Dollars & Cents
End Function

Private 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 Function
    
Private 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 = Result
End Function
    
Private 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 Select
End Function
 
Upvote 0
arvind,

Welcome to the MrExcel board.


Before the macro:


Excel Workbook
AB
1Rs. 1
2Rs. 77
3Rs. 100
4Rs. 391
5Rs. 500
6Rs. 1,1
7Rs. 1,77
8Rs. 1,100
9Rs. 1,391
10Rs. 1,500
11Rs. 10,1
12Rs. 10,77
13Rs. 10,100
14Rs. 10,391
15Rs. 10,500
16Rs. 2,1,1
17Rs. 2,1,77
18Rs. 2,1,391
19Rs. 2,1,500
20Rs. 2,10,1
21Rs. 2,10,77
22Rs. 2,10,100
23Rs. 2,10,500
24Rs. 999,9,999
25Rs. 999,999,999
26
Sheet1



After the macro:


Excel Workbook
AB
1Rs. 1One
2Rs. 77Seventy Seven
3Rs. 100One Hundred
4Rs. 391Three Hundred Ninety One
5Rs. 500Five Hundred
6Rs. 1,1One Thousand One
7Rs. 1,77One Thousand Seventy Seven
8Rs. 1,100One Thousand One Hundred
9Rs. 1,391One Thousand Three Hundred Ninety One
10Rs. 1,500One Thousand Five Hundred
11Rs. 10,1Ten Thousand One
12Rs. 10,77Ten Thousand Seventy Seven
13Rs. 10,100Ten Thousand One Hundred
14Rs. 10,391Ten Thousand Three Hundred Ninety One
15Rs. 10,500Ten Thousand Five Hundred
16Rs. 2,1,1Two Lacs One Thousand One
17Rs. 2,1,77Two Lacs One Thousand Seventy Seven
18Rs. 2,1,391Two Lacs One Thousand Three Hundred Ninety One
19Rs. 2,1,500Two Lacs One Thousand Five Hundred
20Rs. 2,10,1Two Lacs Ten Thousand One
21Rs. 2,10,77Two Lacs Ten Thousand Seventy Seven
22Rs. 2,10,100Two Lacs Ten Thousand One Hundred
23Rs. 2,10,500Two Lacs Ten Thousand Five Hundred
24Rs. 999,9,999Nine Hundred Ninety Nine Lacs Nine Thousand Nine Hundred Ninety Nine
25Rs. 999,999,999Nine Hundred Ninety Nine Lacs Nine Hundred Ninety Nine Thousand Nine Hundred Ninety Nine
26
Sheet1




Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

Adding the Macro
1. Copy the below macro, by highlighting the macro code and pressing the keys CTRL+C
2. Open your workbook
3. Press the keys ALT+F11 to open the Visual Basic Editor
4. Press the keys ALT+I to activate the Insert menu
5. Press M to insert a Standard Module
6. Paste the code by pressing the keys CTRL+V
7. Press the keys ALT+Q to exit the Editor, and return to Excel.

Code:
Option Explicit
Sub SplitData()
Dim c As Range, a As Long, b As Long
Dim MyH As String, MyK As String, MyS As String
Dim Sp, Sp2
Dim Hold As String
For Each c In Range("A1", Range("A" & Rows.Count).End(xlUp))
  b = 0
  On Error Resume Next
  b = Application.WorksheetFunction.Find(",", c, 1)
  On Error GoTo 0
  If b = 0 Then
    Sp = Split(c.Value, " ")
    a = UBound(Sp)
    c.Offset(, 1) = SpellNumber(Sp(a))
  Else
    Sp = Split(c.Value, " ")
    Sp2 = Split(Sp(1), ",")
    Hold = "": MyH = "": MyK = "": MyS = ""
    For b = LBound(Sp2) To UBound(Sp2)
      Select Case b
        Case 0    'Lacs, MyS
          MyS = Sp2(0)
        Case 1    'Thousand, MyK
          If Len(Sp2(1)) = 1 Then
            MyK = "00" & Sp2(1)
          ElseIf Len(Sp2(1)) = 2 Then
            MyK = "0" & Sp2(1)
          Else
            MyK = Sp2(1)
          End If
        Case 2    'Hundred, MyH
          If Len(Sp2(2)) = 1 Then
            MyH = "00" & Sp2(2)
          ElseIf Len(Sp2(2)) = 2 Then
            MyH = "0" & Sp2(2)
          Else
            MyH = Sp2(2)
          End If
      End Select
    Next b
    Hold = Hold & MyS & MyK & MyH
    c.Offset(, 1) = SpellNumber(Hold)
  End If
Next c
End Sub


Function SpellNumber(ByVal MyNumber)
'
' http://support.microsoft.com/kb/213360
' =SpellNumber(32.50)
' =SpellNumber(A1)
'
Dim Dollars, Cents, Temp
Dim DecimalPlace, Count
ReDim Place(9) As String
Place(2) = " Thousand "
Place(3) = " Lacs "     '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
SpellNumber = Dollars
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


Then run the "SplitData" macro.
 
Upvote 0
here is a solution for upto 9 digits & 2 decimal places

Code:
Option Base 0
Option Explicit
 
Dim ones(0 To 19) As String
Dim tens(0 To 9) As String
Dim words As String
Dim c As Range
Const tenpow3 As String = " thousand "
Const tenpow2 As String = " hundred "
Const tenpow1 As String = " "
 
' This is a function to output the numeric values to text
' This works for numbers upto 9 digits and 2 decimal places
' This function has 5 arguments
' r - the reference to the cell to be converted
' with_currency - boolean - optional argument to set the currency notation on/off (default is TRUE)
' curr_name - string - the name of the currency, ignored if with_currency is False (default is "Rupees")
' unit_name - string - the name of the unit, ignored if with_currency is False (default is "Paise")
' indian_num_sys - - boolean - optional argument to set the output format based on indian number system on/off (default is TRUE)
Function ToWords(ByVal r As Range, Optional ByVal with_currency As Boolean = True, Optional curr_name As String = "Rupees", Optional unit_name As String = "Paise", Optional indian_num_sys As Boolean = True) As String
If r.Cells.Count > 1 Then
    ToWords = ""
    Exit Function
End If
Dim i As Integer, rupee As Double, paise As Integer
 
rupee = Int(r.Value)
paise = Int((r.Value - Int(r.Value)) * 100)
 
i = 0
 
ones(0) = "  "
ones(1) = " one "
ones(2) = " two "
ones(3) = " three "
ones(4) = " four "
ones(5) = " five "
ones(6) = " six "
ones(7) = " seven "
ones(8) = " eight "
ones(9) = " Nine "
ones(10) = " ten "
ones(11) = " eleven "
ones(12) = " twelve "
ones(13) = " thirteen "
ones(14) = " fourteen "
ones(15) = " fifteen "
ones(16) = " sixteen "
ones(17) = " seventeen "
ones(18) = " eighteen "
ones(19) = " nineteen "
tens(0) = "  "
tens(1) = "  "
tens(2) = " twenty "
tens(3) = " thirty "
tens(4) = " forty "
tens(5) = " fifty "
tens(6) = " sixty "
tens(7) = "seventy "
tens(8) = " eighty "
tens(9) = " ninety "
 
words = vbNullString
 
If indian_num_sys Then
    getword Int(rupee / 10 ^ 7), " crore "
    getword Int((rupee Mod 10 ^ 7) / 10 ^ 5), " lakh "
Else
    getword Int((rupee Mod 10 ^ 9) / 10 ^ 8), " Hundred "
    getword Int((rupee Mod 10 ^ 8) / 10 ^ 6), " Million "
    getword Int((rupee Mod 10 ^ 6) / 10 ^ 5), " Hundred "
End If
getword Int((rupee Mod 10 ^ 5) / 10 ^ 3), tenpow3
getword Int((rupee Mod 10 ^ 3) / 100), tenpow2
getword Int((rupee Mod 10 ^ 2)), tenpow1
If with_currency Then
    If r.Value >= 1 Then
        words = curr_name & words
    End If
 
    If paise Then
        words = words & unit_name
    End If
End If
If paise Then
    getword Int((paise Mod 10 ^ 2)), " "
End If
 
ToWords = Application.WorksheetFunction.Proper(Application.WorksheetFunction.Trim(words))
End Function
 
 
Function getword(n As Long, ch As String)
If (n<= 19) Then
    words = words & ones(n)
Else
    words = words & tens(Int(n / 10)) & ones(n Mod 10)
End If
If n Then
    words = words & ch
End If
End Function

Excel Workbook
CD
12987,654,321.11Rupees Ninety Eight Crore Seventy Six Lakh Fifty Four Thousand Three Hundred Twenty One Paise Eleven
13987,654,321.00Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One
14987,654,321.00Rupees Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One
15987,654,321.11$ Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One Cents Eleven
16987,654,321.11Rupees Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One Paise Eleven
Sheet1
Cell Formulas
RangeFormula
D12=towords(C12)
D13=towords(C13,FALSE,,,FALSE)
D14=towords(C14,,,,FALSE)
D15=towords(C15,,"$","Cents",FALSE)
D16=towords(C16,,,,FALSE)
 
Upvote 0
Thanks dear for ur valuable suggesstions. But problem is tht I'm just a novice user in excel and all of these suggestions are confusing me. Plz forgive me for my less knowledge in excel.
 
Upvote 0
Thanks Sankar. Your formula works the best for Indian scenario.

here is a solution for upto 9 digits & 2 decimal places

Code:
Option Base 0
Option Explicit
 
Dim ones(0 To 19) As String
Dim tens(0 To 9) As String
Dim words As String
Dim c As Range
Const tenpow3 As String = " thousand "
Const tenpow2 As String = " hundred "
Const tenpow1 As String = " "
 
' This is a function to output the numeric values to text
' This works for numbers upto 9 digits and 2 decimal places
' This function has 5 arguments
' r - the reference to the cell to be converted
' with_currency - boolean - optional argument to set the currency notation on/off (default is TRUE)
' curr_name - string - the name of the currency, ignored if with_currency is False (default is "Rupees")
' unit_name - string - the name of the unit, ignored if with_currency is False (default is "Paise")
' indian_num_sys - - boolean - optional argument to set the output format based on indian number system on/off (default is TRUE)
Function ToWords(ByVal r As Range, Optional ByVal with_currency As Boolean = True, Optional curr_name As String = "Rupees", Optional unit_name As String = "Paise", Optional indian_num_sys As Boolean = True) As String
If r.Cells.Count > 1 Then
    ToWords = ""
    Exit Function
End If
Dim i As Integer, rupee As Double, paise As Integer
 
rupee = Int(r.Value)
paise = Int((r.Value - Int(r.Value)) * 100)
 
i = 0
 
ones(0) = "  "
ones(1) = " one "
ones(2) = " two "
ones(3) = " three "
ones(4) = " four "
ones(5) = " five "
ones(6) = " six "
ones(7) = " seven "
ones(8) = " eight "
ones(9) = " Nine "
ones(10) = " ten "
ones(11) = " eleven "
ones(12) = " twelve "
ones(13) = " thirteen "
ones(14) = " fourteen "
ones(15) = " fifteen "
ones(16) = " sixteen "
ones(17) = " seventeen "
ones(18) = " eighteen "
ones(19) = " nineteen "
tens(0) = "  "
tens(1) = "  "
tens(2) = " twenty "
tens(3) = " thirty "
tens(4) = " forty "
tens(5) = " fifty "
tens(6) = " sixty "
tens(7) = "seventy "
tens(8) = " eighty "
tens(9) = " ninety "
 
words = vbNullString
 
If indian_num_sys Then
    getword Int(rupee / 10 ^ 7), " crore "
    getword Int((rupee Mod 10 ^ 7) / 10 ^ 5), " lakh "
Else
    getword Int((rupee Mod 10 ^ 9) / 10 ^ 8), " Hundred "
    getword Int((rupee Mod 10 ^ 8) / 10 ^ 6), " Million "
    getword Int((rupee Mod 10 ^ 6) / 10 ^ 5), " Hundred "
End If
getword Int((rupee Mod 10 ^ 5) / 10 ^ 3), tenpow3
getword Int((rupee Mod 10 ^ 3) / 100), tenpow2
getword Int((rupee Mod 10 ^ 2)), tenpow1
If with_currency Then
    If r.Value >= 1 Then
        words = curr_name & words
    End If
 
    If paise Then
        words = words & unit_name
    End If
End If
If paise Then
    getword Int((paise Mod 10 ^ 2)), " "
End If
 
ToWords = Application.WorksheetFunction.Proper(Application.WorksheetFunction.Trim(words))
End Function
 
 
Function getword(n As Long, ch As String)
If (n<= 19) Then
    words = words & ones(n)
Else
    words = words & tens(Int(n / 10)) & ones(n Mod 10)
End If
If n Then
    words = words & ch
End If
End Function

Excel Workbook
CD
12987,654,321.11Rupees Ninety Eight Crore Seventy Six Lakh Fifty Four Thousand Three Hundred Twenty One Paise Eleven
13987,654,321.00Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One
14987,654,321.00Rupees Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One
15987,654,321.11$ Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One Cents Eleven
16987,654,321.11Rupees Nine Hundred Eighty Seven Million Six Hundred Fifty Four Thousand Three Hundred Twenty One Paise Eleven
Sheet1
Cell Formulas
RangeFormula
D12=towords(C12)
D13=towords(C13,FALSE,,,FALSE)
D14=towords(C14,,,,FALSE)
D15=towords(C15,,"$","Cents",FALSE)
D16=towords(C16,,,,FALSE)
 
Upvote 0

Forum statistics

Threads
1,225,157
Messages
6,183,250
Members
453,152
Latest member
ChrisMd

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