+ Reply to Thread
Results 1 to 6 of 6

Apply filter then subtotal

  1. #1
    Registered User
    Join Date
    11-22-2008
    Location
    house
    Posts
    68

    Apply filter then subtotal

    Hi there,

    I have a spreadsheet where users will filter it using autofilter. I then have two cells where the val/volume of each account is totalled, this works fine. However I would also like to be able to say which is the most recurring product within the account and how many times it occurs.

    I have attached my sheet below, I hope this helps. Eg, Account 1 worst product is..... with a volume of...

    Is this possible?
    Thanks
    Attached Files Attached Files
    Last edited by staples; 10-13-2009 at 01:54 PM.

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

    Re: Apply filter then subtotal

    This link may help.

    http://www.ozgrid.com/Excel/excel-subtotal-function.htm

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

    Re: Apply filter then subtotal

    Try this formula in C4 for the most frequent product

    =INDEX(B7:B140,MODE(IF(SUBTOTAL(3,OFFSET(B7,ROW(B7:B140)-ROW(B7),,)),MATCH(B7:B140,B7:B140,0))))

    This is an "array formula" which needs to be confirmed with CTRL+SHIFT+ENTER so that curly braces like { and } appear around the formula in the formula bar

    Now in D4 for the number.....

    =SUMPRODUCT(SUBTOTAL(3,OFFSET(B7,ROW(B7:B140)-ROW(B7),,)),--(B7:B140=C4))

  4. #4
    Registered User
    Join Date
    11-22-2008
    Location
    house
    Posts
    68

    Re: Apply filter then subtotal

    Hi,

    Thanks for the quick replies.

    ncmay - I will check out that site a little futher, thanks.

    daddylonglegs - both formulas work perfect, thanks for that. I was wondering I could ask for your help once more. I am curious weather there would be a way to perhaps show the volume of entries per account per period, sort of like a trend. Eg, F1:K1 would read P01, P02, P03 etc, with the count of each beneath this, based on the autofilter selection of account, so therefore the count would update similar to the formulas you produced before. So, if the user were to select the sheet would look like:

    P01 P02 P03 P04....
    3 3 0 1

    Again, I tried to have a bit of play around however fell at the first hurdle!

    Any help would be really appreciated
    Thanks again

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

    Re: Apply filter then subtotal

    You can use a formula similar to the SUMPRODUCT formula I used above, i.e. in F2 copied across

    =SUMPRODUCT(SUBTOTAL(3,OFFSET($E7,ROW($E7:$E140)-ROW($E7),,)),--(RIGHT($E7:$E140,3)=F1))

  6. #6
    Registered User
    Join Date
    11-22-2008
    Location
    house
    Posts
    68

    Re: Apply filter then subtotal

    Thanks for that mate, that works great!

+ 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