+ Reply to Thread
Results 1 to 26 of 26

SUM IF Error

  1. #1
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Angry SUM IF Error

    Hello!

    Have used this forum many times and it has been so useful, but now I'm really stuck and I can't find any answers on here so thought I would ask my first question!

    I have attached a spreadheet that should sum the value in column G based on the value of column A* however it seems to think that "1-02" & "2-14" are the same number and sums it all?!?!

    Im guessing that this is a date thing maybe?? But does anybody have an idea of how i can get around this as I cant change the code and I need a seperate sum of each code?

    Many Thanks in advance for all your help.

    Sam



    SUMIF Error.xlsx

  2. #2
    Forum Expert
    Join Date
    04-22-2013
    Location
    .
    MS-Off Ver
    .
    Posts
    4,418

    Re: SUM IF Error

    Hi, I think you are right in that sumif is looking at them as dates. I don't think there is a way to force sumif to stop doing this though so you may be better with a formula like:
    =SUM(IF(F1:F2=A1,G1:G2,0))
    it's an array formula so you need to confirm with ctrl+shift+enter.

  3. #3
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: SUM IF Error

    Welcome to the forum and wow! What an interesting feature you've unearthed!

    I have no idea why SUMIF can't cope with interpreting the string as text, but will investigate. In the meantime, there is also this (non-array) alternative:

    =SUMPRODUCT(($F1:$F2=$A2)*$G1:$G2)

    Regards
    Click * below if this answer helped

    Advanced Excel Techniques: http://excelxor.com/

  4. #4
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Re: SUM IF Error

    That has returned the correct results.

    Thank you so much!

  5. #5
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Re: SUM IF Error

    Quote Originally Posted by XOR LX View Post
    Welcome to the forum and wow! What an interesting feature you've unearthed!

    I have no idea why SUMIF can't cope with interpreting the string as text, but will investigate. In the meantime, there is also this (non-array) alternative:

    =SUMPRODUCT(($F1:$F2=$A2)*$G1:$G2)

    Regards

    It's been driving me crazy, but your formula seems to work prefectly. Thank You!

  6. #6
    Forum Contributor
    Join Date
    03-17-2005
    Location
    Canterbury, Kent
    MS-Off Ver
    2003, 2010
    Posts
    285

    Re: SUM IF Error

    Are these meant to be dates?

    Windy

  7. #7
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Re: SUM IF Error

    No, they are account codes...

    Sam

  8. #8
    Forum Expert
    Join Date
    04-22-2013
    Location
    .
    MS-Off Ver
    .
    Posts
    4,418

    Re: SUM IF Error

    The problem is presumably, that
    =datevalue("1-02")
    and
    =datevalue("2-14")
    both return 41671 and presumably that is how sumif is comparing them.

  9. #9
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: SUM IF Error

    Sure, but that doesn't explain why SUMIF converts them to numerics?! SUMPRODUCT, for example, doesn't have a problem with seeing them as the text values they really are...

    Regards

  10. #10
    Forum Guru romperstomper's Avatar
    Join Date
    11-04-2008
    Location
    A1
    MS-Off Ver
    Most
    Posts
    12,302

    Re: SUM IF Error

    SUMIF has always had the issue of converting any criterion it can to a number. If you use:
    =SUMIF($F:$F,$A2&"*",$G:$G)
    it will work - assuming, of course, that all the accounts have the same number of digits and layout. SUMPRODUCT is safer!
    Remember what the dormouse said
    Feed your head

  11. #11
    Valued Forum Contributor AZ-XL's Avatar
    Join Date
    03-22-2013
    Location
    Azerbaijan, Baku
    MS-Off Ver
    Excel 2007
    Posts
    603

    Re: SUM IF Error

    In my sheet sumif gave correct answers (100, 250)
    Maybe this formula may help
    =SUMPRODUCT(("'"&$F$1:$F$2="'"&A1)*$G$1:$G$2)
    Appreciate the help? CLICK *

  12. #12
    Forum Expert
    Join Date
    04-22-2013
    Location
    .
    MS-Off Ver
    .
    Posts
    4,418

    Re: SUM IF Error

    Was just playing about, and thought it was interesting that using vba:
    Please Login or Register  to view this content.
    returns 100...

  13. #13
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: SUM IF Error

    Quote Originally Posted by ragulduy View Post
    Was just playing about, and thought it was interesting that using vba:
    Please Login or Register  to view this content.
    returns 100...
    ?? The plot thickens!

  14. #14
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: SUM IF Error

    Quote Originally Posted by romperstomper View Post
    SUMIF has always had the issue of converting any criterion it can to a number. If you use:
    =SUMIF($F:$F,$A2&"*",$G:$G)
    it will work - assuming, of course, that all the accounts have the same number of digits and layout. SUMPRODUCT is safer!
    Very nice, Rory!

  15. #15
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: SUM IF Error

    If you put 0E1 in A1 and 0E2 in A2 then this formula gives you 2

    =COUNTIF(A1:A2,A1)

    i.e. COUNTIF treats those as the same value (as does SUMIF)

    See here
    Audere est facere

  16. #16
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: SUM IF Error

    Quote Originally Posted by daddylonglegs View Post
    If you put 0E1 in A1 and 0E2 in A2 then this formula gives you 2

    =COUNTIF(A1:A2,A1)

    i.e. COUNTIF treats those as the same value (as does SUMIF)

    See here
    Excellent. Thanks, daddylonglegs.

    Guess it raises the question of how "useful" a decision it was in the first place to formulate the syntax of SUMIF, etc. as such...

    Regards

  17. #17
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: SUM IF Error

    The way it works has some advantages, e.g.

    =COUNTIF(A:A,2)

    and

    =COUNTIF(A:A,"2")

    should both give you the same result, both counting all 2s in column A, text-formatted or numeric......but this is the other side of the coin

  18. #18
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: SUM IF Error

    Actually I'd rather not have that be the result. I prefer to know which are text and which are numeric...

    Cheers

  19. #19
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Re: SUM IF Error

    Although I hugely appreciate all your help, (Even though it gave the correct reult) I could not get my head around the sum product formula and how it calculated, I also had to do a vlookup for another piece of info as well and wasn't sure how to add that in! So I have chosen to solve this issue a slightly different way. I realise this option may not be applicable for all but it seems to be working for me so far!

    I have changed the data I am running this formula on. So now instead of being '1-02' I have added a prefix of "/" to give "/1-02". I can now run my formula based on this new field:
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    I realise this may not be the most efficient solution but it gives me the correct result

    Many Thanks,

    Sam

  20. #20
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,733

    Re: SUM IF Error

    As I understand it, SUMIF/COUNTIF etc. evaluates the string expression that denotes the condition, trying to make sense of it as best it can. The results above, though unexpected for the unwary, are logically correct. Rory's approach is how you can get round it.

    Pete

  21. #21
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,733

    Re: SUM IF Error

    Quote Originally Posted by sam01722 View Post
    I realise this may not be the most efficient solution but it gives me the correct result
    Hi Sam,

    if you changed the codes to use an underscore instead of the hyphen then it should work okay, and you wouldn't need the prefix.

    Hope this helps.

    Pete

  22. #22
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Re: SUM IF Error

    Quote Originally Posted by Pete_UK View Post
    Hi Sam,

    if you changed the codes to use an underscore instead of the hyphen then it should work okay, and you wouldn't need the prefix.

    Hope this helps.

    Pete
    Unfortunatley the ERP system I am querying the data from only allows for hyphens and not underscores to form the code. But that is still very interesting to know.

    Sam

  23. #23
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,733

    Re: SUM IF Error

    Once you have imported the data you could use Find & Replace to change - to _ for your column containing the codes, or you could use a helper column to do that with the SUBSTITUTE function and use the helper column as the reference in your formulae, so you still have the original codes if you need to export anything back.

    Pete

  24. #24
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Re: SUM IF Error

    Quote Originally Posted by Pete_UK View Post
    Once you have imported the data you could use Find & Replace to change - to _ for your column containing the codes, or you could use a helper column to do that with the SUBSTITUTE function and use the helper column as the reference in your formulae, so you still have the original codes if you need to export anything back.

    Pete
    Thats interesting, I never knew about the substitute formula. I have just given it a try and it seems to only work for one "-". For example, The code "1-01-000" changes to "1_01-000" ....?

  25. #25
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,733

    Re: SUM IF Error

    It worked for me - I put this value in A1:

    1-01-000

    and this formula in B1:

    =SUBSTITUTE(A1,"-","_")

    and this was the result:

    1_01_000

    Hope this helps.

    Pete

  26. #26
    Registered User
    Join Date
    03-28-2014
    Location
    Salisbury, England
    MS-Off Ver
    Excel 2013
    Posts
    12

    Re: SUM IF Error

    Quote Originally Posted by Pete_UK View Post
    It worked for me - I put this value in A1:

    1-01-000

    and this formula in B1:

    =SUBSTITUTE(A1,"-","_")

    and this was the result:

    1_01_000

    Hope this helps.

    Pete
    Ahhhhhh yes it does indeed work :/ Not sure what ! did last time haha!!!!! Thanks

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Excel macro (compile error. syntax error.) error
    By salar_younis in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 01-06-2014, 06:11 AM
  2. Receiving following error “Complie error : syntax error” Help
    By masond3 in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 11-02-2012, 10:19 AM
  3. Error "run-time Error '1004': General Odbc Error
    By D4WNO77 in forum Access Tables & Databases
    Replies: 2
    Last Post: 07-16-2012, 09:55 AM
  4. Error 75 File/Path access error, sometimes Error 1004
    By smokebreak in forum Excel Programming / VBA / Macros
    Replies: 14
    Last Post: 02-16-2011, 02:35 PM
  5. [SOLVED] Error Handling - On Error GoTo doesn't trap error successfully
    By David in forum Excel Programming / VBA / Macros
    Replies: 9
    Last Post: 02-16-2006, 02:10 PM

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1