1. Welcome to Chandoo.org Forums. Short message for you

    Hi Guest,

    Thanks for joining Chandoo.org forums. We are here to make you awesome in Excel. Before you post your first question, please read this short introduction guide. When posting or responding to questions please remember our values at Chandoo.org are: Humility, Passion, Fun, Awesomeness, Simplicity, Sharing Remember that we have people here for whom English is not there first language and we need to allow for this in our dealings.

    Yours,
    Chandoo
  2. Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  3. When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Need help with if is error and sumproduct excel formula

Discussion in 'Ask an Excel Question' started by gmfston, Feb 12, 2018.

  1. gmfston

    gmfston New Member

    Messages:
    19
    Hello Ninjas,

    I created a combined if is error and sumproduct formula but it is populating zero values. I am having difficulty determining what the issue is. I am looking for a formula that looks at the matching data in columns a, b and c and populates the amounts from sheet 2, column d to column e, sheet 1. The expected results are populated in column F, sheet 1.

    Best regards,
    Gina

    Attached Files:

  2. John Jairo V

    John Jairo V Well-Known Member

    Messages:
    452
    Hi, @gmfston!

    You can try this formula:
    =SUMIFS('Sheet 2'!D:D,'Sheet 2'!A:A,A7,'Sheet 2'!B:B,B7,'Sheet 2'!C:C,C7)

    P.D. Your Data in C column of Sheet2 have an additional space at the end of the phrases. I delete it (with TRIM function and copy-paste as values in C). Blessings!

    Attached Files:

  3. p45cal

    p45cal Well-Known Member

    Messages:
    1,083
    1. As John Jairo V said, trim the values in column C of sheet2.

    2. To adjust your formulae, in C9 instead of:
    Code (vb):
    =IF(ISERROR(SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9),('Sheet 2'!$B$6:$B$17='Sheet 1'!B9),('Sheet 2'!$C$6:$C$17,'Sheet 1'!C9),'Sheet 2'!$D$6:$D$17)),0,SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9),('Sheet 2'!$B$6:$B$17='Sheet 1'!B9),('Sheet 2'!$C$6:$C$17,'Sheet 1'!C9),'Sheet 2'!$D$6:$D$17))
    try:
    Code (vb):
    =IF(ISERROR(SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9)*('Sheet 2'!$B$6:$B$17='Sheet 1'!B9)*('Sheet 2'!$C$6:$C$17='Sheet 1'!C9),'Sheet 2'!$D$6:$D$17)),0,SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9)*('Sheet 2'!$B$6:$B$17='Sheet 1'!B9)*('Sheet 2'!$C$6:$C$17='Sheet 1'!C9),'Sheet 2'!$D$6:$D$17))
    I'll try to highlight the differences below but I may not have caught them all. In any event, it seems to give the correct results.

    =IF(ISERROR(SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9),('Sheet 2'!$B$6:$B$17='Sheet 1'!B9),('Sheet 2'!$C$6:$C$17,'Sheet 1'!C9),'Sheet 2'!$D$6:$D$17)),0,SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9),('Sheet 2'!$B$6:$B$17='Sheet 1'!B9),('Sheet 2'!$C$6:$C$17,'Sheet 1'!C9),'Sheet 2'!$D$6:$D$17))
    =IF(ISERROR(SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9)*('Sheet 2'!$B$6:$B$17='Sheet 1'!B9)*('Sheet 2'!$C$6:$C$17='Sheet 1'!C9),'Sheet 2'!$D$6:$D$17)),0,SUMPRODUCT(('Sheet 2'!$A$6:$A$17='Sheet 1'!A9)*('Sheet 2'!$B$6:$B$17='Sheet 1'!B9)*('Sheet 2'!$C$6:$C$17='Sheet 1'!C9),'Sheet 2'!$D$6:$D$17))
    Last edited: Feb 12, 2018
    gmfston likes this.
  4. gmfston

    gmfston New Member

    Messages:
    19
    Hello John,

    Thank you so much. The revisions worked.:)

    Best regards,
    Gina

Share This Page