+ Reply to Thread
Results 1 to 7 of 7

Identifying unique values within a row whilst suming a column array

  1. #1
    Registered User
    Join Date
    07-12-2012
    Location
    California
    MS-Off Ver
    Excel 2007
    Posts
    7

    Identifying unique values within a row whilst suming a column array

    I am looking to sum a column of values, summing only values that are
    1) is a "Weight" value
    2) is greater than 0.001
    3) is a unique value in its row

    I can achieve the first and second points using SUMIF() and working with arrays (which I have recently learned about), but need help with #3. I am currently summing the data by hand, but as the data grows in rows and columns, I would prefer a more automated method, and one less prone to human error. I'm not sure there is another way to approach this problem other than a cell function?

    Attached is a sample of the data. You can see the correct sums in "True total weights". I would like to achieve the same result in the yellow highlighted cells. Currently, values less than 0.001 are expressed in red fonts, and values that are duplicates in its row are highlighted pink.
    Attached Files Attached Files

  2. #2
    Forum Contributor BenMiller's Avatar
    Join Date
    12-06-2011
    Location
    New Jersey
    MS-Off Ver
    Excel 2010
    Posts
    254

    Re: Identifying unique values within a row whilst suming a column array

    Try

    =SUMPRODUCT(--($A1:$A20="Weight"),--(B1:B20>0.001),--(COUNTIF(B1:B20,B1:B20)=1),B1:B20)

  3. #3
    Registered User
    Join Date
    07-12-2012
    Location
    California
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Identifying unique values within a row whilst suming a column array

    Not quite. I think the COUNTIF(B1:B20,B1:B20)=1 portion is checking for unique values within the column. I am looking to sum the column, but only values that are unique for its row in the table.

    Is that more clearly phrased? I'm sorry if that was unclear before.

    Also, if I may ask, what does the -- before each array in SUMPRODUCT() for?

  4. #4
    Forum Contributor BenMiller's Avatar
    Join Date
    12-06-2011
    Location
    New Jersey
    MS-Off Ver
    Excel 2010
    Posts
    254

    Re: Identifying unique values within a row whilst suming a column array

    Ahh, I'm not sure if I have a solution off-hand. It would involve a complicated array formula, at the very least.
    And the -- forces the array of TRUE/FALSE into 1/0.

  5. #5
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    Microsoft 365
    Posts
    14,726

    Re: Identifying unique values within a row whilst suming a column array

    Try this formula in B22 copied across

    =IFERROR(SUMPRODUCT(($A1:$A20="Weight")*(B1:B20>0.001)*(COUNTIF(OFFSET($B1:$L20,ROW($B1:$L20)-ROW($B1),0,1),B1:B20)=1),B1:B20),0)

    It looks like there are no countable values in the columns that have #VALUE! errors so the above will return zero for those columns. If you have circumstances where there might be countable values in the same column as you have errors then switch to this "array formula"

    =SUM(IF(ISNUMBER(B1:B20),IF(($A1:$A20="Weight")*(B1:B20>0.001)*(COUNTIF(OFFSET($B1:$L20,ROW($B1:$L20)-ROW($B1),0,1),B1:B20)=1),B1:B20)))

    confirmed with CTRL+SHIFT+ENTER
    Audere est facere

  6. #6
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Identifying unique values within a row whilst suming a column array

    id create another using =IF(AND($A2="weight",B2>0.001,COUNTIF($B2:$L2,B2)=1),B2,"") table then sum that
    Attached Files Attached Files
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

  7. #7
    Registered User
    Join Date
    07-12-2012
    Location
    California
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Identifying unique values within a row whilst suming a column array

    Both solutions are great ideas and work perfectly. Thank you very much.

+ 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