So problem was the reference in formulas ,  if any formula have reference
like A1:A5 and when it will get evaluate by VBA (i am using Evaluate here)
it will always assume that reference is from activesheet until we provide
full reference like Sheet1!A1:A5, but it is complex to write that code , so
the simple solution would to be to activate that sheet where the formula is
going to be evaluated,

try this code ,


Sub PasteFormula()

    Dim rngRange As Range
    Dim VarArr
    Dim strFormula As String
    Dim varEle
    Dim lngR As Long
    Dim lngC As Long
    Dim lngCount As Long
    Dim wksSheet As Worksheet
    Dim wksLastActive As Worksheet

    strFormula = InputBox("Enter formula name to replace with values")
    lngCount = 0
    Application.ScreenUpdating = False
    Set wksLastActive = ThisWorkbook.ActiveSheet
    For Each wksSheet In ThisWorkbook.Worksheets
        Set rngRange = wksSheet.UsedRange
        If Not rngRange Is Nothing Then
            VarArr = rngRange.Formula
                If IsArray(VarArr) Then
                    wksSheet.Activate
                    For lngR = LBound(VarArr) To UBound(VarArr)
                        For lngC = LBound(VarArr) To UBound(VarArr, 2)
                            If Not IsEmpty(VarArr(lngR, lngC)) Then
                                If UCase(VarArr(lngR, lngC)) Like "*" &
UCase(strFormula) & "*" Then
                                    VarArr(lngR, lngC) =
Evaluate(VarArr(lngR, lngC))
                                    lngCount = lngCount + 1
                                End If
                            End If
                        Next lngC
                    Next lngR
                    wksSheet.UsedRange.Value = VarArr
                End If
                Set rngRange = Nothing
        End If
    Next wksSheet
    wksLastActive.Activate
    Application.ScreenUpdating = True
    MsgBox strFormula & " has been replaced in " & lngCount & " Cells",
vbInformation

End Sub



On Fri, Sep 27, 2013 at 12:08 AM, Mukesh Kumar <mukeshka...@gmail.com>wrote:

> Rajan Ji,
>
> Plz see attached file. I have inserted the macro code in it. But it is
> giving wrong results. Plz check.
>
> Regards,
> Mukesh Kumar
>
>
> On Thu, Sep 26, 2013 at 9:45 PM, rajan verma <rajanverma1...@gmail.com>wrote:
>
>> use this one.
>>
>> Sub PasteFormula()
>>
>>     Dim rngRange As Range
>>     Dim VarArr
>>     Dim strFormula As String
>>     Dim varEle
>>     Dim lngR As Long
>>     Dim lngC As Long
>>     Dim lngCount As Long
>>     Dim wksSheet As Worksheet
>>
>>     strFormula = InputBox("Enter formula name to replace with values")
>>     lngCount = 0
>>     For Each wksSheet In ThisWorkbook.Worksheets
>>         Set rngRange = wksSheet.UsedRange
>>         If Not rngRange Is Nothing Then
>>             VarArr = rngRange.Formula
>>                 If IsArray(VarArr) Then
>>                     For lngR = LBound(VarArr) To UBound(VarArr)
>>                         For lngC = LBound(VarArr) To UBound(VarArr, 2)
>>                             If Not IsEmpty(VarArr(lngR, lngC)) Then
>>                                 If UCase(VarArr(lngR, lngC)) Like "*" &
>> UCase(strFormula) & "*" Then
>>                                     VarArr(lngR, lngC) =
>> Evaluate(VarArr(lngR, lngC))
>>                                     lngCount = lngCount + 1
>>                                 End If
>>                             End If
>>                         Next lngC
>>                     Next lngR
>>                 End If
>>         End If
>>        wksSheet.UsedRange.Value = VarArr
>>     Next wksSheet
>>
>>     MsgBox strFormula & " has been replaced in " & lngCount & " Cells",
>> vbInformation
>>
>> End Sub
>>
>>
>>
>> On Thu, Sep 26, 2013 at 10:14 AM, rajan verma 
>> <rajanverma1...@gmail.com>wrote:
>>
>>>
>>> Try this one
>>>
>>> Sub PasteFormula()
>>>
>>>     Dim rngRange As Range
>>>     Dim VarArr
>>>     Dim strFormula As String
>>>     Dim varEle
>>>     Dim lngR As Long
>>>     Dim lngC As Long
>>>     Dim lngCount As Long
>>>     Dim wksSheet As Worksheet
>>>
>>>     strFormula = InputBox("Enter formula name to replace with values")
>>>     lngCount = 0
>>>     For Each wksSheet In ThisWorkbook.Worksheets
>>>         Set rngRange = wksSheet.UsedRange
>>>         If Not rngRange Is Nothing Then
>>>             VarArr = rngRange.Formula
>>>                 If IsArray(VarArr) Then
>>>                     For lngR = LBound(VarArr) To UBound(VarArr)
>>>                         For lngC = LBound(VarArr) To UBound(VarArr, 2)
>>>                             If Not IsEmpty(VarArr(lngR, lngC)) Then
>>>                                 If UCase(VarArr(lngR, lngC)) Like "*" &
>>> UCase(strFormula) & "*" Then
>>>                                     VarArr(lngR, lngC) =
>>> Evaluate(VarArr(lngR, lngC))
>>>                                     lngCount = lngCount + 1
>>>                                 End If
>>>                             End If
>>>                         Next lngC
>>>                     Next lngR
>>>                 End If
>>>         End If
>>>     Next wksSheet
>>>     ActiveSheet.UsedRange.Value = VarArr
>>>     MsgBox strFormula & " has been replaced in " & lngCount & " Cells",
>>> vbInformation
>>>
>>> End Sub
>>>
>>>
>>>
>>> On Thu, Sep 26, 2013 at 6:37 AM, Mukesh Kumar <mukeshka...@gmail.com>wrote:
>>>
>>>> Rajan ji , this macro code is limited to one sheet only. I want the
>>>> macro that works upon all sheets at once.
>>>>
>>>> Regards,
>>>> Mukesh Kumar
>>>>
>>>>
>>>> On Thu, Sep 26, 2013 at 3:39 PM, rajan verma 
>>>> <rajanverma1...@gmail.com>wrote:
>>>>
>>>>> HI Mukesh
>>>>>
>>>>> i have seen this query many time on this group and another forums,
>>>>> please try this macro
>>>>>
>>>>>
>>>>> Sub PasteFormula()
>>>>>
>>>>>     Dim rngRange As Range
>>>>>     Dim VarArr
>>>>>     Dim strFormula As String
>>>>>     Dim varEle
>>>>>     Dim lngR As Long
>>>>>     Dim lngC As Long
>>>>>     Dim lngCount As Long
>>>>>
>>>>>     Set rngRange = ActiveSheet.UsedRange
>>>>>     VarArr = rngRange.Formula
>>>>>     strFormula = InputBox("Enter formula name to replace with values")
>>>>>     lngCount = 0
>>>>>     For lngR = LBound(VarArr) To UBound(VarArr)
>>>>>         For lngC = LBound(VarArr) To UBound(VarArr, 2)
>>>>>             If Not IsEmpty(VarArr(lngR, lngC)) Then
>>>>>                 If UCase(VarArr(lngR, lngC)) Like "*" &
>>>>> UCase(strFormula) & "*" Then
>>>>>                     VarArr(lngR, lngC) = Evaluate(VarArr(lngR, lngC))
>>>>>                     lngCount = lngCount + 1
>>>>>                 End If
>>>>>             End If
>>>>>         Next lngC
>>>>>     Next lngR
>>>>>     ActiveSheet.UsedRange.Value = VarArr
>>>>>     MsgBox strFormula & " is replace in " & lngCount & " Cells",
>>>>> vbInformation
>>>>>
>>>>> End Sub
>>>>>
>>>>>
>>>>>
>>>>> On Thu, Sep 26, 2013 at 3:40 AM, Mukesh Kumar 
>>>>> <mukeshka...@gmail.com>wrote:
>>>>>
>>>>>> Hi experts,
>>>>>>
>>>>>> I need a macro code to paste special a particular formula across many
>>>>>> sheets. Every sheet contains different types of formulas, but i have to
>>>>>> paste special a particular /specific formula.
>>>>>>
>>>>>>
>>>>>> Please help me out.
>>>>>>
>>>>>>
>>>>>> Regards,
>>>>>> Mukesh Kumar
>>>>>>
>>>>>> --
>>>>>> Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be?
>>>>>> It’s =TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @
>>>>>> https://www.facebook.com/discussexcel
>>>>>>
>>>>>> FORUM RULES
>>>>>>
>>>>>> 1) Use concise, accurate thread titles. Poor thread titles, like
>>>>>> Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need
>>>>>> Advice will not get quick attention or may not be answered.
>>>>>> 2) Don't post a question in the thread of another member.
>>>>>> 3) Don't post questions regarding breaking or bypassing any security
>>>>>> measure.
>>>>>> 4) Acknowledge the responses you receive, good or bad.
>>>>>> 5) Jobs posting is not allowed.
>>>>>> 6) Sharing copyrighted material and their links is not allowed.
>>>>>>
>>>>>> NOTE : Don't ever post confidential data in a workbook. Forum owners
>>>>>> and members are not responsible for any loss.
>>>>>> ---
>>>>>> You received this message because you are subscribed to the Google
>>>>>> Groups "MS EXCEL AND VBA MACROS" group.
>>>>>> To unsubscribe from this group and stop receiving emails from it,
>>>>>> send an email to excel-macros+unsubscr...@googlegroups.com.
>>>>>> To post to this group, send email to excel-macros@googlegroups.com.
>>>>>> Visit this group at http://groups.google.com/group/excel-macros.
>>>>>> For more options, visit https://groups.google.com/groups/opt_out.
>>>>>>
>>>>>
>>>>>
>>>>>
>>>>> --
>>>>> Regards
>>>>> Rajan verma
>>>>> +91 7838100659
>>>>>
>>>>> --
>>>>> Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be?
>>>>> It’s =TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @
>>>>> https://www.facebook.com/discussexcel
>>>>>
>>>>> FORUM RULES
>>>>>
>>>>> 1) Use concise, accurate thread titles. Poor thread titles, like
>>>>> Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need
>>>>> Advice will not get quick attention or may not be answered.
>>>>> 2) Don't post a question in the thread of another member.
>>>>> 3) Don't post questions regarding breaking or bypassing any security
>>>>> measure.
>>>>> 4) Acknowledge the responses you receive, good or bad.
>>>>> 5) Jobs posting is not allowed.
>>>>> 6) Sharing copyrighted material and their links is not allowed.
>>>>>
>>>>> NOTE : Don't ever post confidential data in a workbook. Forum owners
>>>>> and members are not responsible for any loss.
>>>>> ---
>>>>> You received this message because you are subscribed to the Google
>>>>> Groups "MS EXCEL AND VBA MACROS" group.
>>>>> To unsubscribe from this group and stop receiving emails from it, send
>>>>> an email to excel-macros+unsubscr...@googlegroups.com.
>>>>> To post to this group, send email to excel-macros@googlegroups.com.
>>>>> Visit this group at http://groups.google.com/group/excel-macros.
>>>>> For more options, visit https://groups.google.com/groups/opt_out.
>>>>>
>>>>
>>>>  --
>>>> Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be?
>>>> It’s =TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @
>>>> https://www.facebook.com/discussexcel
>>>>
>>>> FORUM RULES
>>>>
>>>> 1) Use concise, accurate thread titles. Poor thread titles, like Please
>>>> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
>>>> will not get quick attention or may not be answered.
>>>> 2) Don't post a question in the thread of another member.
>>>> 3) Don't post questions regarding breaking or bypassing any security
>>>> measure.
>>>> 4) Acknowledge the responses you receive, good or bad.
>>>> 5) Jobs posting is not allowed.
>>>> 6) Sharing copyrighted material and their links is not allowed.
>>>>
>>>> NOTE : Don't ever post confidential data in a workbook. Forum owners
>>>> and members are not responsible for any loss.
>>>> ---
>>>> You received this message because you are subscribed to the Google
>>>> Groups "MS EXCEL AND VBA MACROS" group.
>>>> To unsubscribe from this group and stop receiving emails from it, send
>>>> an email to excel-macros+unsubscr...@googlegroups.com.
>>>> To post to this group, send email to excel-macros@googlegroups.com.
>>>> Visit this group at http://groups.google.com/group/excel-macros.
>>>> For more options, visit https://groups.google.com/groups/opt_out.
>>>>
>>>
>>>
>>>
>>> --
>>> Regards
>>> Rajan verma
>>> +91 7838100659
>>>
>>
>>
>>
>> --
>> Regards
>> Rajan verma
>> +91 7838100659
>>
>> --
>> Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be? It’s
>> =TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @
>> https://www.facebook.com/discussexcel
>>
>> FORUM RULES
>>
>> 1) Use concise, accurate thread titles. Poor thread titles, like Please
>> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
>> will not get quick attention or may not be answered.
>> 2) Don't post a question in the thread of another member.
>> 3) Don't post questions regarding breaking or bypassing any security
>> measure.
>> 4) Acknowledge the responses you receive, good or bad.
>> 5) Jobs posting is not allowed.
>> 6) Sharing copyrighted material and their links is not allowed.
>>
>> NOTE : Don't ever post confidential data in a workbook. Forum owners and
>> members are not responsible for any loss.
>> ---
>> You received this message because you are subscribed to the Google Groups
>> "MS EXCEL AND VBA MACROS" group.
>> To unsubscribe from this group and stop receiving emails from it, send an
>> email to excel-macros+unsubscr...@googlegroups.com.
>> To post to this group, send email to excel-macros@googlegroups.com.
>> Visit this group at http://groups.google.com/group/excel-macros.
>> For more options, visit https://groups.google.com/groups/opt_out.
>>
>
>  --
> Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be? It’s
> =TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @
> https://www.facebook.com/discussexcel
>
> FORUM RULES
>
> 1) Use concise, accurate thread titles. Poor thread titles, like Please
> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
> will not get quick attention or may not be answered.
> 2) Don't post a question in the thread of another member.
> 3) Don't post questions regarding breaking or bypassing any security
> measure.
> 4) Acknowledge the responses you receive, good or bad.
> 5) Jobs posting is not allowed.
> 6) Sharing copyrighted material and their links is not allowed.
>
> NOTE : Don't ever post confidential data in a workbook. Forum owners and
> members are not responsible for any loss.
> ---
> You received this message because you are subscribed to the Google Groups
> "MS EXCEL AND VBA MACROS" group.
> To unsubscribe from this group and stop receiving emails from it, send an
> email to excel-macros+unsubscr...@googlegroups.com.
> To post to this group, send email to excel-macros@googlegroups.com.
> Visit this group at http://groups.google.com/group/excel-macros.
> For more options, visit https://groups.google.com/groups/opt_out.
>



-- 
Regards
Rajan verma
+91 7838100659

-- 
Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be? It’s 
=TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @ 
https://www.facebook.com/discussexcel

FORUM RULES

1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get 
quick attention or may not be answered.
2) Don't post a question in the thread of another member.
3) Don't post questions regarding breaking or bypassing any security measure.
4) Acknowledge the responses you receive, good or bad.
5) Jobs posting is not allowed.
6) Sharing copyrighted material and their links is not allowed.

NOTE  : Don't ever post confidential data in a workbook. Forum owners and 
members are not responsible for any loss.
--- 
You received this message because you are subscribed to the Google Groups "MS 
EXCEL AND VBA MACROS" group.
To unsubscribe from this group and stop receiving emails from it, send an email 
to excel-macros+unsubscr...@googlegroups.com.
To post to this group, send email to excel-macros@googlegroups.com.
Visit this group at http://groups.google.com/group/excel-macros.
For more options, visit https://groups.google.com/groups/opt_out.

Reply via email to