Consulting

Results 1 to 12 of 12

Thread: Error 438

  1. #1

    Unhappy Error 438

    Sorry I know this been asked before by other users so forgive me but I am getting the same error (Error 438), I am new to VBA so any help would be appreciated:

    Sub ADDITUP()
    Dim AAdd As Variant
    Dim DAdd As Variant
    DateRangeStart = InputBox("Please select start date (01/01/2018)")
    DaterangeEnd = InputBox("Please select end date (01/01/2018)")
    DAdd = Application.WorksheetFunction.SumIfs(Sheet1!AL, Sheet1!AH, ">=" & DateRangeStart, Sheet1!AH, "<=" & DaterangeEnd)  <---Error is here
    'MsgBox DAdd
    'MsgBox DateRangeStart
    'MsgBox DaterangeEnd
    End Sub

  2. #2
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    perhaps related with european data format vs us format in vba.

    google search results re this issue:
    https://www.google.com.tr/search?rlz....0.Swsd2SV5poo
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  3. #3
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,720
    Location
    Sheet1!AL and Sheet1!AH are not valid ranges in VBA (or anywhere else). You should use Sheets("Sheet1").Range("AL:AL") for example. Also, if you have Excel 2003 or earlier, there is no SumIfs available.
    Be as you wish to seem

  4. #4
    No that doesn't seem to work:

    I've changed the code but now I get the result as zero:

    Sub ADDITUP()
    Dim AAdd As Variant
    Dim DAdd As Variant
    Dim aFORange As Range
    Dim aFODateRange As Range
    Dim DaterangeEnd As Variant
    Dim DateRangeStart As Variant
    Dim AAdd As Variant
    Dim DAdd As Variant
    Dim fORange As Range
    Dim fODateRange As Range
    Dim DaterangeEnd As Variant
    Dim DateRangeStart As Variant
    Dim ws As Worksheet
    Set ws = Sheet1
    Set fODateRange = Sheets("Sheet1").Range("AL2:AL17")
    Set fORange = Sheets("Sheet1").Range("AH2:AH17")
    DateRangeStart = InputBox("Please select start date (01/01/2018)")
    DaterangeEnd = InputBox("Please select end date (01/01/2018)")
    DAdd = Application.WorksheetFunction.SumIfs(fODateRange, fORange, "=>" & DateRangeStart, fORange, "<=" & DaterangeEnd)
    MsgBox DAdd
    'MsgBox DateRangeStart
    'MsgBox DaterangeEnd
    End Sub

  5. #5
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,720
    Location
    You've changed the criteria for some reason. It should be ">=" and not "=>"
    Be as you wish to seem

  6. #6
    Moderator VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    AH and AL are not valid range assignments
    AH:AH and AL:AL are valid

    Lose the spaces, except around the Ampersands

    I'm not sure, but try
    DAdd = Application.WorksheetFunction.SumIfs(Sheet1!AL:AL, Sheet1!AH:AH,">=" & DateRangeStart, Sheet1!AH:AH."<=" & DaterangeEnd)
    Those Ranges might not work because a blank cell is less than DateRangeEnd

    See what this does
    Sub ADDITUP()
    Dim DAdd As Variant
    Dim DateRangeStart as Date
    Dim DateRangeEnd As Date
    Dim SumRange As Range
    Dim CritRange As Range
    
    With Sheets("Sheet1")
      'AL1 with no headers. Use AL2 with headers
      Set SumRange = Range(.Range("AL1"), .Cells(Rows.Count, "AL").End(xlUp))
      Set CritRange = SumRange.Offset(0, -4)
    End With
    
    'The Returns from InputBoxes are Strings. 
    'Specifying the Month eliminates International Date Format confusion
    'Format the converted Dates from the inputBoxes as desired
    DateRangeStart = Format(CDate(InputBox("Please select start date (01 Jan, 2018)")), "dd/mm/yyyy")
    DateRangeEnd = Format(CDate(InputBox("Please select end date (Jan 31, 2018)") "dd/mm/yyyy")
    
    DAdd = Application.WorksheetFunction.SumIfs(SumRange, CritRange, ">=" & DateRangeStart, CritRange, "<=" & DaterangeEnd)
    
    'MsgBox DAdd
    'MsgBox DateRangeStart
    'MsgBox DaterangeEnd
    End Sub
    Note: if Column AH is formatted As Dates of any display format, you should not need to Format DateRangeStart and DateRangeEnd, only CDate the InputBoxes returns.
    Last edited by SamT; 06-12-2018 at 02:01 AM.
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

  7. #7
    Thank you for your help so far SamT I am getting a "1004 error - Method 'ramge' of object'_Worksheet'Failed on line

    Set SumRange = Range(.Range("AL2"), .Cells(Rows.Count, "AL").End(xlUp))

  8. #8
    Quote Originally Posted by Aflatoon View Post
    You've changed the criteria for some reason. It should be ">=" and not "=>"
    Yes that was me playing around with the code to see if made any difference to it. Thanks for pointing it out

  9. #9
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,720
    Location
    There are two missing full stops there:

    Set SumRange = .Range(.Range("AL2"), .Cells(.Rows.Count, "AL").End(xlUp))
    Be as you wish to seem

  10. #10
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,720
    Location
    I'd suggest you convert the date values to numbers like this:

    DAdd = Application.WorksheetFunction.SumIfs(fODateRange, fORange, ">=" & CLng(DateRangeStart), fORange, "<=" & Clng(DaterangeEnd))
    Be as you wish to seem

  11. #11
    Thank you to both of you it now works!!

    You are both lovely people!!

  12. #12
    Completed Code:

    Sub ADDITUP()
    Dim DAdd As Variant
    Dim DateRangeStart As Date
    Dim DateRangeEnd As Date
    Dim SumRange As Range
    Dim CritRange As Range
    
    
    With Sheets("Sheet1")
      'AL1 with no headers. Use AL2 with headers
      Set SumRange = .Range(.Range("AL2"), .Cells(.Rows.Count, "AL").End(xlUp))
      Set CritRange = SumRange.Offset(0, -4)
    End With
    
    
    'The Returns from InputBoxes are Strings.
    'Specifying the Month eliminates International Date Format confusion
    'Format the converted Dates from the inputBoxes as desired
    DateRangeStart = CDate(InputBox("Please select start date (01 Jan, 2018)"))
    DateRangeEnd = CDate(InputBox("Please select end date (Jan 31, 2018)"))
    
    
    
    
    DAdd = Application.WorksheetFunction.SumIfs(SumRange, CritRange, ">=" & CLng(DateRangeStart), CritRange, "<=" & CLng(DateRangeEnd))
    
    
    MsgBox DAdd
    'MsgBox DateRangeStart
    'MsgBox DaterangeEnd
    End Sub

Tags for this Thread

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •