+ Reply to Thread
Results 1 to 5 of 5

Sumif & Countif (excluding hidden rows)

  1. #1
    Registered User
    Join Date
    01-31-2013
    Location
    US
    MS-Off Ver
    Excel 2010
    Posts
    22

    Sumif & Countif (excluding hidden rows)

    Can the sumif function and countif function be used over a range of data that has hidden rows, and not include those rows? Like is there a way to select only 'active' cells?

    Thanks!

  2. #2
    Forum Guru benishiryo's Avatar
    Join Date
    03-25-2011
    Location
    Singapore
    MS-Off Ver
    Excel 2013
    Posts
    5,147

    Re: Sumif & Countif (excluding hidden rows)

    hi JimExcel. assuming your data is in A1:B10 and you want to count how many As are in A1:A10, then:
    =SUMPRODUCT((A1:A10="a")*(SUBTOTAL(103,OFFSET(A1,ROW(A1:A10)-ROW(A1),))))

    to sum up B1:B10 based on whether A1:A10 is equals to "a", then:
    =SUMPRODUCT((A1:A10="a")*(SUBTOTAL(103,OFFSET(A1,ROW(A1:A10)-ROW(A1),)))*(B1:B10))

    SUBTOTAL ignores hidden rows. SUMPRODUCT is an alternative for SUMIF & COUNTIF

    Thanks, if you have clicked on the * and added our rep.

    If you're satisfied with the answer, click Thread Tools above your first post, select "Mark your thread as Solved".

    "Contentment is not the fulfillment of what you want, but the realization of what you already have."


    Tips & Tutorials I Compiled | How to Get Quick & Good Answers

  3. #3
    Registered User
    Join Date
    01-31-2013
    Location
    US
    MS-Off Ver
    Excel 2010
    Posts
    22

    Re: Sumif & Countif (excluding hidden rows)

    THank you! What if my rows are constantly changing. Is there an easy shortcut to use instead of defining the last row A10 in your example?

  4. #4
    Registered User
    Join Date
    01-31-2013
    Location
    US
    MS-Off Ver
    Excel 2010
    Posts
    22

    Re: Sumif & Countif (excluding hidden rows)

    Nevermind, for my purposes I can just use subtotal. Thanks for you help.

  5. #5
    Forum Expert Kevin UK's Avatar
    Join Date
    12-07-2010
    Location
    Radstock, Somerset
    MS-Off Ver
    365
    Posts
    1,922

    Re: Sumif & Countif (excluding hidden rows)

    Hi JimExcel

    Also look at the AGGREGATE function as by your profile you have Excel 2010.

    http://office.microsoft.com/en-gb/ex...010338704.aspx
    Regards Kevin


    Merged Cells (They are the work of the devil!!!)

+ 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