+ Reply to Thread
Results 1 to 10 of 10

Sum according to Auto filter non visible cells

  1. #1
    Forum Contributor
    Join Date
    11-28-2008
    Location
    Reykjavík, Iceland
    MS-Off Ver
    Any of: 2003 & 2007
    Posts
    412

    Sum according to Auto filter non visible cells

    Hi,

    The whole "story" can be found inside the attached WB.

    I tried using SUBTOTATL but no luck.

    As always, I prefer without helper column(s) and/or VBA - but If not - I will, probably, have to compromise.

    Thanks, Elm
    Attached Files Attached Files
    Last edited by ElmerS; 08-09-2009 at 11:07 PM.

  2. #2
    Forum Expert contaminated's Avatar
    Join Date
    05-07-2009
    Location
    Baku, Azerbaijan
    MS-Off Ver
    Excel 2013
    Posts
    1,430

    Re: Sum according to Auto filter non visible cells

    U can use array formulae to solve your issue.
    In D27
    Please Login or Register  to view this content.
    D25 is 5
    But i think this is not what you're lookin' for.

    VBA codin' is required here in order to do exactly what you want.
    In my opinion here are no formulas that able to sum only visible cells... if only not UDF..
    Люди, питающие благие намерения, как раз и становятся чудовищами.

    Regards, ?Born in USSR?
    Vusal M Dadashev

    Baku, Azerbaijan

  3. #3
    Forum Contributor
    Join Date
    07-24-2009
    Location
    Valrico, FL USA
    MS-Off Ver
    Excel 2016
    Posts
    358

    Re: Sum according to Auto filter non visible cells

    You can use subtotal if you filter column A greater than 100 then filter column B greater than 5.

    Norman

  4. #4
    Forum Contributor
    Join Date
    11-28-2008
    Location
    Reykjavík, Iceland
    MS-Off Ver
    Any of: 2003 & 2007
    Posts
    412

    Re: Sum according to Auto filter non visible cells

    Thank you, ContaminatedWitExce.

    Of course you are absolutely right because it was my mistake.

    Cell B11 should also be 6.00 - and in that case your formula is not appropriate.

    Still waiting for a result one way or the other.

    btw. the empty cells in col. "A" are not "zeros" - they may be treated as "BLANKS".
    (This is the way i got that WB).
    =========================

    Thank you too, ncmay,

    This is a workaround and can be considered but I still wonder if there is some formula that can do it without filtering col. "B".

    Elm
    Last edited by ElmerS; 08-09-2009 at 05:27 PM.

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

    Re: Sum according to Auto filter non visible cells

    try
    array entered
    =SUMPRODUCT((SUBTOTAL(3,OFFSET(B5:B24,ROW(B5:B24)-MIN(ROW(B5:B24)),,-1)))*((B5:B24)>5)*(A5:A24))
    note your sheet has text in cells A5:A24 which stops this working
    select col a /data /text to columns /click finish
    that should sort it ive done it on attached formula is in d29
    notes
    range (B5:B24) is being checked for >5
    range A5:A24 is the one being summed hence the offset -1 col b to col a
    OFFSET(B5:B24,ROW(B5:B24)-MIN(ROW(B5:B24)),,-1))
    Attached Files Attached Files
    Last edited by martindwilson; 08-09-2009 at 07:15 PM.
    "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

  6. #6
    Forum Contributor
    Join Date
    11-28-2008
    Location
    Reykjavík, Iceland
    MS-Off Ver
    Any of: 2003 & 2007
    Posts
    412

    Re: Sum according to Auto filter non visible cells

    Perfect Score, Martin.

    One small remark: by using SUMPRODUCT, in that case, you don't need it to be an Array formula.

    Thanks a lot, Elm
    Last edited by ElmerS; 08-09-2009 at 11:34 PM.

  7. #7
    Forum Expert
    Join Date
    06-18-2004
    Location
    Canada
    MS-Off Ver
    Office 2016
    Posts
    1,474

    Re: Sum according to Auto filter non visible cells

    Here's another way...

    =SUMPRODUCT(--(B5:B25>5),SUBTOTAL(9,OFFSET(A5:A25,ROW(A5:A25)-ROW(A5),0,1)

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

    Re: Sum according to Auto filter non visible cells

    i dont know why i put array entered anyway!

  9. #9
    Forum Contributor
    Join Date
    11-28-2008
    Location
    Reykjavík, Iceland
    MS-Off Ver
    Any of: 2003 & 2007
    Posts
    412

    Re: Sum according to Auto filter non visible cells

    Quote Originally Posted by Domenic View Post
    Here's another way...

    =SUMPRODUCT(--(B5:B25>5),SUBTOTAL(9,OFFSET(A5:A25,ROW(A5:A25)-ROW(A5),0,1)
    Thanks, Domenic.

  10. #10
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Sum according to Auto filter non visible cells

    and as you no doubt know generally speaking Volatile Sumproducts will kill performance -- volatile here given use of OFFSET ... and obviously filtering is a Volatile action in it's own right (in part because of SUBTOTAL Function)

+ 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