VBA: update cell formula returns "TRUE" instead of value

BKChedlia

New Member
Joined
Jun 15, 2016
Messages
41
Dear all,

I have a VBA code which allows me to update cell formula in all folder's file but the formula returns "TRUE" instead of value
PS: the same formula works manually.
This is my code :

Code:
Sub Example()    Dim MyPath As String, FilesInPath As String
    Dim MyFiles() As String, Fnum As Long
    Dim mybook As Workbook
    Dim CalcMode As Long
    Dim sh As Worksheet
    Dim ErrorYes As Boolean
    Dim NewFormula As String
    
    
    'NewFromula = true instead of value
    NewFormula = "=((SUMIFS('Bank Guarantees'!AK:AK,'Bank Guarantees'!V:V,C4,'Bank Guarantees'!L:L,CONCATENATE(" >= ",TODAY()),'Bank Guarantees'!U:U,C11)+SUMIFS('Bank Guarantees'!AK:AK,'Bank Guarantees'!V:V,C4,'Bank Guarantees'!L:L,36161,'Bank Guarantees'!U:U,C11)))"
    'Fill in the path\folder where the files are
    MyPath = "C:\Users\cben\Downloads\test"


    'Add a slash at the end if the user forget it
    If Right(MyPath, 1) <> "\" Then
        MyPath = MyPath & "\"
    End If


    'If there are no Excel files in the folder exit the sub
    FilesInPath = Dir(MyPath & "*.xl*")
    If FilesInPath = "" Then
        MsgBox "No files found"
        Exit Sub
    End If


    'Fill the array(myFiles)with the list of Excel files in the folder
    Fnum = 0
    Do While FilesInPath <> ""
        Fnum = Fnum + 1
        ReDim Preserve MyFiles(1 To Fnum)
        MyFiles(Fnum) = FilesInPath
        FilesInPath = Dir()
    Loop


    'Change ScreenUpdating, Calculation and EnableEvents
    With Application
        CalcMode = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
        .EnableEvents = False
    End With


    'Loop through all files in the array(myFiles)
    If Fnum > 0 Then
        For Fnum = LBound(MyFiles) To UBound(MyFiles)
            Set mybook = Nothing
            On Error Resume Next
           ' Set mybook = Workbooks.Open(MyPath & MyFiles(Fnum))
            Set mybook = Workbooks.Open(MyPath & MyFiles(Fnum), _
    Password:="RiskAssurance")
            On Error GoTo 0


            If Not mybook Is Nothing Then




                'Change cell value(s) in one worksheet in mybook
                On Error Resume Next
                With mybook.Worksheets("Output")
               
               .Unprotect Password:="xxxx"
                   If .ProtectContents = False Then
                        .Range("I22").Formula = NewFormula
                         .Range("I22").Calculate
                         .Protect Password:="xxxx"
                    Else
                        ErrorYes = True
                    End If
                End With




                If Err.Number > 0 Then
                    ErrorYes = True
                    Err.Clear
                    'Close mybook without saving
                    mybook.Close savechanges:=False
                Else
                    'Save and close mybook
                    mybook.Close savechanges:=True
                End If
                On Error GoTo 0
            Else
                'Not possible to open the workbook
                ErrorYes = True
            End If


        Next Fnum
    End If


    If ErrorYes = True Then
        MsgBox "There are problems in one or more files, possible problem:" _
             & vbNewLine & "protected workbook/sheet or a sheet/range that not exist"
    End If


    'Restore ScreenUpdating, Calculation and EnableEvents
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = CalcMode
    End With
End Sub
Thank you for help
 
Last edited:

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Hia
As you are just using NewFormula once get rid of it & put the actual formula straight into the cell
Code:
.Unprotect Password:="xxxx"
                   If .ProtectContents = False Then
                        .Range("I22").Formula = "=((SUMIFS('Bank Guarantees'!AK:AK,'Bank Guarantees'!V:V,C4,'Bank Guarantees'!L:L,CONCATENATE(" >= ",TODAY()),'Bank Guarantees'!U:U,C11)+SUMIFS('Bank Guarantees'!AK:AK,'Bank Guarantees'!V:V,C4,'Bank Guarantees'!L:L,36161,'Bank Guarantees'!U:U,C11)))"
                         .Range("I22").Calculate
                         .Protect Password:="xxxx"
                    Else
                        ErrorYes = True
                    End If
                End With
 
Upvote 0
Dear Fluff,

Same error, maybe because in the formula, it's looking into another sheet 'Bank guarantees' which is protected too.

Help please
 
Upvote 0
What happens if you manually enter the formula in the cell?
 
Upvote 0
You need double quotes inside the string.
Try changing
CONCATENATE(" >= ",TODAY())
to
CONCATENATE("">="",TODAY())

Hope this helps

M.
 
Upvote 0
Without the double quotes the code was comparing two strings
"=((SUMIFS(........CONCATENATE("
with
",TODAY()............"

As = (Chr 61) is greater than , (Chr 44) the formula was returning True.

M.
 
Upvote 0

Forum statistics

Threads
1,224,827
Messages
6,181,194
Members
453,021
Latest member
pingpong7117

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