+ Reply to Thread
Results 1 to 6 of 6

SUMPRODUCT formula returning #VALUE! error

  1. #1
    Valerie
    Guest

    SUMPRODUCT formula returning #VALUE! error

    Hello, All!

    I'm having trouble getting this formula to work:

    {SUMPRODUCT(--(WBS!$A$2:$A$423=$A46)*(--(WBS!$B$2:$B$423=$F46)*WBS!$E$2:$E$423))}

    1st section is comparing a text field
    2nd section is comparing a number field
    3rd section is asking for a result of a text field

    I tried separating the sections to determine which is producing the error
    and I don't receive an error message, although the numbers they produced
    didn't appear to be the correct location of the WBS sheet. I need it to
    compare two columns to determine the correct cell to pull since there are
    duplicates in both columns but with the criteria from both columns, the line
    is unique.
    I did import these from an SAP download, but have replaced formatting with
    correct formatting by pulling value of the text into a new column with
    VALUE() formula then pasting value.
    What am I missing?

  2. #2
    Peo Sjoblom
    Guest

    Re: SUMPRODUCT formula returning #VALUE! error

    =SUMPRODUCT(--(WBS!$A$2:$A$423=$A46),--(WBS!$B$2:$B$423=$F46),WBS!$E$2:$E$423)


    --

    Regards,

    Peo Sjoblom

    http://nwexcelsolutions.com



    "Valerie" <[email protected]> wrote in message
    news:[email protected]...
    > Hello, All!
    >
    > I'm having trouble getting this formula to work:
    >
    > {SUMPRODUCT(--(WBS!$A$2:$A$423=$A46)*(--(WBS!$B$2:$B$423=$F46)*WBS!$E$2:$E$423))}
    >
    > 1st section is comparing a text field
    > 2nd section is comparing a number field
    > 3rd section is asking for a result of a text field
    >
    > I tried separating the sections to determine which is producing the error
    > and I don't receive an error message, although the numbers they produced
    > didn't appear to be the correct location of the WBS sheet. I need it to
    > compare two columns to determine the correct cell to pull since there are
    > duplicates in both columns but with the criteria from both columns, the
    > line
    > is unique.
    > I did import these from an SAP download, but have replaced formatting with
    > correct formatting by pulling value of the text into a new column with
    > VALUE() formula then pasting value.
    > What am I missing?




  3. #3
    Forum Contributor
    Join Date
    08-28-2005
    Posts
    298

    SUMPRODUCT formula returning #VALUE! error

    hi!

    =SUMPRODUCT(--(WBS!$A$2:$A$423=C1),--(WBS!$B$2:$B$423=$F46),--(WBS!$E$2:$E$423))

    assuming that the text you comparing is in C1

    -via135




    Quote Originally Posted by Valerie
    Hello, All!

    I'm having trouble getting this formula to work:

    {SUMPRODUCT(--(WBS!$A$2:$A$423=$A46)*(--(WBS!$B$2:$B$423=$F46)*WBS!$E$2:$E$423))}

    1st section is comparing a text field
    2nd section is comparing a number field
    3rd section is asking for a result of a text field

    I tried separating the sections to determine which is producing the error
    and I don't receive an error message, although the numbers they produced
    didn't appear to be the correct location of the WBS sheet. I need it to
    compare two columns to determine the correct cell to pull since there are
    duplicates in both columns but with the criteria from both columns, the line
    is unique.
    I did import these from an SAP download, but have replaced formatting with
    correct formatting by pulling value of the text into a new column with
    VALUE() formula then pasting value.
    What am I missing?

  4. #4
    Valerie
    Guest

    Re: SUMPRODUCT formula returning #VALUE! error

    Thanks, Peo. I'm now getting 0 instead of the error code, and that's still
    not correct. I also tried the other suggestion from via135, but still
    received the error code. Any other ideas?

    "Peo Sjoblom" wrote:

    > =SUMPRODUCT(--(WBS!$A$2:$A$423=$A46),--(WBS!$B$2:$B$423=$F46),WBS!$E$2:$E$423)
    >
    >
    > --
    >
    > Regards,
    >
    > Peo Sjoblom
    >
    > http://nwexcelsolutions.com
    >
    >
    >
    > "Valerie" <[email protected]> wrote in message
    > news:[email protected]...
    > > Hello, All!
    > >
    > > I'm having trouble getting this formula to work:
    > >
    > > {SUMPRODUCT(--(WBS!$A$2:$A$423=$A46)*(--(WBS!$B$2:$B$423=$F46)*WBS!$E$2:$E$423))}
    > >
    > > 1st section is comparing a text field
    > > 2nd section is comparing a number field
    > > 3rd section is asking for a result of a text field
    > >
    > > I tried separating the sections to determine which is producing the error
    > > and I don't receive an error message, although the numbers they produced
    > > didn't appear to be the correct location of the WBS sheet. I need it to
    > > compare two columns to determine the correct cell to pull since there are
    > > duplicates in both columns but with the criteria from both columns, the
    > > line
    > > is unique.
    > > I did import these from an SAP download, but have replaced formatting with
    > > correct formatting by pulling value of the text into a new column with
    > > VALUE() formula then pasting value.
    > > What am I missing?

    >
    >
    >


  5. #5
    Peo Sjoblom
    Guest

    Re: SUMPRODUCT formula returning #VALUE! error

    If you want to return a text value you cannot use sumproduct, I erroneously
    assumed that E2:E423 was numbers. sumproduct can only return a numeric
    result so it can count a text column or a number column or it can sum a
    number column. If you want to return one text value from E2:E423 where
    A2:A423 is A46 and B2:B423 is F46 then you can use

    =INDEX(WBS!$E$2:$E$423,MATCH(1,(WBS!$A$2:$A$423=$A46)*(WBS!$B$2:$B$423=$F46),0))

    entered with ctrl + shift & enter


    --

    Regards,

    Peo Sjoblom

    http://nwexcelsolutions.com





    "Valerie" <[email protected]> wrote in message
    news:[email protected]...
    > Thanks, Peo. I'm now getting 0 instead of the error code, and that's
    > still
    > not correct. I also tried the other suggestion from via135, but still
    > received the error code. Any other ideas?
    >
    > "Peo Sjoblom" wrote:
    >
    >> =SUMPRODUCT(--(WBS!$A$2:$A$423=$A46),--(WBS!$B$2:$B$423=$F46),WBS!$E$2:$E$423)
    >>
    >>
    >> --
    >>
    >> Regards,
    >>
    >> Peo Sjoblom
    >>
    >> http://nwexcelsolutions.com
    >>
    >>
    >>
    >> "Valerie" <[email protected]> wrote in message
    >> news:[email protected]...
    >> > Hello, All!
    >> >
    >> > I'm having trouble getting this formula to work:
    >> >
    >> > {SUMPRODUCT(--(WBS!$A$2:$A$423=$A46)*(--(WBS!$B$2:$B$423=$F46)*WBS!$E$2:$E$423))}
    >> >
    >> > 1st section is comparing a text field
    >> > 2nd section is comparing a number field
    >> > 3rd section is asking for a result of a text field
    >> >
    >> > I tried separating the sections to determine which is producing the
    >> > error
    >> > and I don't receive an error message, although the numbers they
    >> > produced
    >> > didn't appear to be the correct location of the WBS sheet. I need it
    >> > to
    >> > compare two columns to determine the correct cell to pull since there
    >> > are
    >> > duplicates in both columns but with the criteria from both columns, the
    >> > line
    >> > is unique.
    >> > I did import these from an SAP download, but have replaced formatting
    >> > with
    >> > correct formatting by pulling value of the text into a new column with
    >> > VALUE() formula then pasting value.
    >> > What am I missing?

    >>
    >>
    >>




  6. #6
    Valerie
    Guest

    Re: SUMPRODUCT formula returning #VALUE! error

    Thanks, Peo!! It worked! I had tried using Index/Match before but with the
    AND function and got nowhere. I will be utilizing this way much more now
    since I work a lot with text! Thanks so much!

    Valerie

    "Peo Sjoblom" wrote:

    > If you want to return a text value you cannot use sumproduct, I erroneously
    > assumed that E2:E423 was numbers. sumproduct can only return a numeric
    > result so it can count a text column or a number column or it can sum a
    > number column. If you want to return one text value from E2:E423 where
    > A2:A423 is A46 and B2:B423 is F46 then you can use
    >
    > =INDEX(WBS!$E$2:$E$423,MATCH(1,(WBS!$A$2:$A$423=$A46)*(WBS!$B$2:$B$423=$F46),0))
    >
    > entered with ctrl + shift & enter
    >
    >
    > --
    >
    > Regards,
    >
    > Peo Sjoblom
    >
    > http://nwexcelsolutions.com
    >
    >
    >
    >
    >
    > "Valerie" <[email protected]> wrote in message
    > news:[email protected]...
    > > Thanks, Peo. I'm now getting 0 instead of the error code, and that's
    > > still
    > > not correct. I also tried the other suggestion from via135, but still
    > > received the error code. Any other ideas?
    > >
    > > "Peo Sjoblom" wrote:
    > >
    > >> =SUMPRODUCT(--(WBS!$A$2:$A$423=$A46),--(WBS!$B$2:$B$423=$F46),WBS!$E$2:$E$423)
    > >>
    > >>
    > >> --
    > >>
    > >> Regards,
    > >>
    > >> Peo Sjoblom
    > >>
    > >> http://nwexcelsolutions.com
    > >>
    > >>
    > >>
    > >> "Valerie" <[email protected]> wrote in message
    > >> news:[email protected]...
    > >> > Hello, All!
    > >> >
    > >> > I'm having trouble getting this formula to work:
    > >> >
    > >> > {SUMPRODUCT(--(WBS!$A$2:$A$423=$A46)*(--(WBS!$B$2:$B$423=$F46)*WBS!$E$2:$E$423))}
    > >> >
    > >> > 1st section is comparing a text field
    > >> > 2nd section is comparing a number field
    > >> > 3rd section is asking for a result of a text field
    > >> >
    > >> > I tried separating the sections to determine which is producing the
    > >> > error
    > >> > and I don't receive an error message, although the numbers they
    > >> > produced
    > >> > didn't appear to be the correct location of the WBS sheet. I need it
    > >> > to
    > >> > compare two columns to determine the correct cell to pull since there
    > >> > are
    > >> > duplicates in both columns but with the criteria from both columns, the
    > >> > line
    > >> > is unique.
    > >> > I did import these from an SAP download, but have replaced formatting
    > >> > with
    > >> > correct formatting by pulling value of the text into a new column with
    > >> > VALUE() formula then pasting value.
    > >> > What am I missing?
    > >>
    > >>
    > >>

    >
    >
    >


+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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