Home |
Search |
Today's Posts |
#1
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
I have created a worksheet consisting of columns consisting of name, work
group ( a 2 digit alpha numeric), gender and then some numerical data. I want to autofilter on work group and then perform analysis on only the visible rows left. Obviously I only want 1 summary row at the bottom which will change as I apply different criteria to the auto filter (by selecting different work groups). I can get count functions to work with sub-total but I need to use the countif function. Any clues? |
#2
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi,
the first solution jumping to my mind would be one of the two: - 1- either you use advanced filter and copy data to a new sheet where you can analyse it or 2- better use Pivot Tables. Will any of these do? Khaldoun Specialized Technologies Saudi Arabia -- Khldoun Specialized Technologies Saudi Arabia "Dr Happy" wrote: I have created a worksheet consisting of columns consisting of name, work group ( a 2 digit alpha numeric), gender and then some numerical data. I want to autofilter on work group and then perform analysis on only the visible rows left. Obviously I only want 1 summary row at the bottom which will change as I apply different criteria to the auto filter (by selecting different work groups). I can get count functions to work with sub-total but I need to use the countif function. Any clues? |
#3
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Here is an example where B2:b20 is filtered, and a condition in A2:A20 is
tested =SUMPRODUCT((SUBTOTAL(3,OFFSET($B$1,ROW($B$2:$B$20 )-ROW($B$1),,1)))*(C2:C20= "a")) -- HTH RP (remove nothere from the email address if mailing direct) "Dr Happy" <Dr wrote in message ... I have created a worksheet consisting of columns consisting of name, work group ( a 2 digit alpha numeric), gender and then some numerical data. I want to autofilter on work group and then perform analysis on only the visible rows left. Obviously I only want 1 summary row at the bottom which will change as I apply different criteria to the auto filter (by selecting different work groups). I can get count functions to work with sub-total but I need to use the countif function. Any clues? |
#4
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
You are either going not far enough, or too far. If you want to ue Filters and SUBTOTAL, then you
need to completely filter your data to get your count, along with your additional criteria from COUNTIF - that is the equivalent of using COUNTIF. So apply another level or two of filtering. Or don't use filters at all, and use pivot tables, hiding what you don't need. Or - use horribly complicated SUMPRODUCT Formulas. HTH, Bernie MS Excel MVP "Dr Happy" <Dr wrote in message ... I have created a worksheet consisting of columns consisting of name, work group ( a 2 digit alpha numeric), gender and then some numerical data. I want to autofilter on work group and then perform analysis on only the visible rows left. Obviously I only want 1 summary row at the bottom which will change as I apply different criteria to the auto filter (by selecting different work groups). I can get count functions to work with sub-total but I need to use the countif function. Any clues? |
#5
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi Roger,
Problem is that it does handle filtered rows, but not rows hidden by some other method. I posted a solution that incorporated a UDF for that case a few days ago, which also handles the filtered data. Might just use that as my standard. -- HTH RP (remove nothere from the email address if mailing direct) "Roger Govier" wrote in message ... Hi Bob That's cool. Never thought about using the Subtotal function inside Sumproduct like that. Regards Roger Govier Bob Phillips wrote: Here is an example where B2:b20 is filtered, and a condition in A2:A20 is tested =SUMPRODUCT((SUBTOTAL(3,OFFSET($B$1,ROW($B$2:$B$20 )-ROW($B$1),,1)))*(C2:C20= "a")) |
#6
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi Roger,
My Excel of choice is still 2000 (£ being my driver :-( ), and that only goes up to 11, so I didn't know that. Thanks, I have learned something. -- HTH RP (remove nothere from the email address if mailing direct) "Roger Govier" wrote in message ... Hi Bob It will handle rows hidden, as opposed to filtered, if you substitute 103 for 3 =SUMPRODUCT((SUBTOTAL(103,OFFSET($B$1,ROW($B$2:$B$ 20)-ROW($B$1),,1)))*(C2:C2 0="a")) This is a feature that is present in Xl2003, and maybe in XL2002(??) Regards Roger Govier Bob Phillips wrote: Hi Roger, Problem is that it does handle filtered rows, but not rows hidden by some other method. I posted a solution that incorporated a UDF for that case a few days ago, which also handles the filtered data. Might just use that as my standard. |
#7
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi Bob
That's cool. Never thought about using the Subtotal function inside Sumproduct like that. Regards Roger Govier Bob Phillips wrote: Here is an example where B2:b20 is filtered, and a condition in A2:A20 is tested =SUMPRODUCT((SUBTOTAL(3,OFFSET($B$1,ROW($B$2:$B$20 )-ROW($B$1),,1)))*(C2:C20= "a")) |
#8
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi Bob
It will handle rows hidden, as opposed to filtered, if you substitute 103 for 3 =SUMPRODUCT((SUBTOTAL(103,OFFSET($B$1,ROW($B$2:$B$ 20)-ROW($B$1),,1)))*(C2:C20="a")) This is a feature that is present in Xl2003, and maybe in XL2002(??) Regards Roger Govier Bob Phillips wrote: Hi Roger, Problem is that it does handle filtered rows, but not rows hidden by some other method. I posted a solution that incorporated a UDF for that case a few days ago, which also handles the filtered data. Might just use that as my standard. |
#9
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi Bob
(£ being my driver :-( ) what other driver is there??? Waiting for Excel 12 perhaps!! I just checked out XL2002 and it does not exist in that version. Regards Roger Govier Bob Phillips wrote: Hi Roger, My Excel of choice is still 2000 (£ being my driver :-( ), and that only goes up to 11, so I didn't know that. Thanks, I have learned something. |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
TRYING TO SET UP EXCEL SPREADSHEET ON MY COMPUTER | New Users to Excel | |||
Can I copy data from only the visible rows in Excel? | Excel Discussion (Misc queries) | |||
Updating rows - Excel Formula or Something Else? | Excel Worksheet Functions | |||
How do I import data into Excel that exceeds 70000 rows? | Excel Discussion (Misc queries) | |||
How do I remove blank rows in Excel? | Excel Discussion (Misc queries) |