subtotal question

ghardy

New Member
Joined
Nov 21, 2005
Messages
1
I have a list of times could be either in [h]:mm format or in minutes formatted as a number. These times represent the length of stay in a service process. With subtotal function I can determine “average, stddev, min and max instantly as I filter the data set based upon selection criteria. It is important to also know the 95th percentile of the filtered-selected data. Is there some way to build a calculation of subtotal functions or another way to display the answer each time I change the selection criteria so that the formula only works against the filtered data the way the subtotal function works?.

additionally I need to put this into a macro where the range for the subtotal will change dynamically. each day the column count can be a different lenght and I need to have the cell range expand or contract similar to the <control-shift-arrow down> method to capture the entire column reguardless of the changing size. this way the macro can be run and it wont be necessary to rekey the formula each day.

Thank you

George Hardy
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,013
Try the following formula that needs to be confirmed with CONTROL+SHIFT+ENTER, not just ENTER...

=PERCENTILE(IF(SUBTOTAL(3,OFFSET(Range,ROW(Range)-MIN(ROW(Range)),0,1)),Range),K)

...where K is the percentile value.

Hope this helps!
 

Forum statistics

Threads
1,082,253
Messages
5,364,045
Members
400,776
Latest member
JimmyLee

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top