Results 1 to 3 of 3
  1. #1
    tagteam is offline Expert
    Windows 7 64bit Access 2010 32bit
    Join Date
    Mar 2013
    Posts
    501

    sum iif not working


    I am trying to sum everything that is not a particular value:

    =Sum(IIf([UpdatedResponsibilityCode]<>1 Or [UpdatedResponsibilityCode]<>3 Or [UpdatedResponsibilityCode]<>6 Or [UpdatedResponsibilityCode]<>7,[NetCharge],0))

    However, when I do this it actually adds all the values for 1,3,6, 7 instead of excluding them.

  2. #2
    June7's Avatar
    June7 is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,772
    Because you use OR, try AND.

    or

    =Sum(IIf(NOT [UpdatedResponsibilityCode] IN (1, 3, 6, 7), [NetCharge], 0))

    or

    =Sum(IIf([UpdatedResponsibilityCode] IN (1, 3, 6, 7), 0, [NetCharge]))
    How to attach file: http://www.accessforums.net/showthread.php?t=70301 To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  3. #3
    ssanfu is offline Master of Nothing
    Windows 7 32bit Access 2010 32bit
    Join Date
    Sep 2010
    Location
    Anchorage, Alaska, USA
    Posts
    9,664
    You didn't provide any test data with expected results, so I created my own test data.

    I entered 10 records for UpdatedResponsibilityCode and numbered 1 - 10
    I entered values 10 - 100 for NetCharge.

    Using your formula
    Code:
    =Sum(IIf([UpdatedResponsibilityCode]<>1 Or [UpdatedResponsibilityCode]<>3 Or [UpdatedResponsibilityCode]<>6 Or [UpdatedResponsibilityCode]<>7,[NetCharge],0))
    resulted a value of 550..... the sum of all [NetCharge] values

    I changed the "OR"s to "AND"s and the result was 380:
    Code:
    =Sum(IIf([UpdatedResponsibilityCode]<>1 and [UpdatedResponsibilityCode]<>3 and [UpdatedResponsibilityCode]<>6 and [UpdatedResponsibilityCode]<>7,[NetCharge],0))



    I try not to use negative logic, so I re-wrote the formula. I changed the original formula by changing the not equal to (<>) to equals (=) and moved the [NetCharge] value to the FALSE clause:
    Code:
    =Sum(IIf([UpdatedResponsibilityCode]=1 Or [UpdatedResponsibilityCode]=3 Or [UpdatedResponsibilityCode]=6 Or [UpdatedResponsibilityCode]=7, 0, [NetCharge]))
    The result is 380.

Please reply to this thread with any new information or opinions.

Similar Threads

  1. Replies: 2
    Last Post: 05-14-2017, 10:07 AM
  2. Working query stops working after importing
    By Abacus1234 in forum Import/Export Data
    Replies: 3
    Last Post: 10-25-2015, 09:12 PM
  3. Replies: 13
    Last Post: 01-22-2015, 05:27 PM
  4. Replies: 1
    Last Post: 12-27-2014, 12:38 PM
  5. Replies: 3
    Last Post: 01-29-2013, 04:34 AM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums