Example file attached (I think)
Example file attached (I think)
Last edited by mjcarman01; 11-19-2017 at 12:48 PM. Reason: Attaching example file
Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? Please don't attach a picture of one (no-one will want to re-type all your stuff before starting).
1. Make sure that your sample data are truly REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.
2. Make sure that your desired solution is also shown (mock up the results manually).
3. Make sure that all confidential information is removed first!!
4. Try to avoid using merged cells. They cause lots of problems!
Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
Glenn
None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU
Try this version
=INDEX(LINEST(INDEX(B2:B60,N(IF(1,MODE.MULT(IF((A2:A60="Site2")*(D2:D60="Pre"),(ROW(B2:B60)-ROW(B2)+1)*{1,1}))))),INDEX(E2:E60,N(IF(1,MODE.MULT(IF((A2:A60="Site2")*(D2:D60="Pre"),(ROW(B2:B60)-ROW(B2)+1)*{1,1})))))^{1,2}),1)
confirmed with CTRL+SHIFT+ENTER
change conditions as required
Audere est facere
This works perfectly, and I am impressed! For the life of me, however, I can no longer follow the formula? I can make out that the following represents the x array:
INDEX(B2:B60,N(IF(1,MODE.MULT(IF((A2:A60="Site2")*(D2:D60="Pre"),(ROW(B2:B60)-ROW(B2)+1)*{1,1})))))
How does this work? It appears that we are creating a vertical array of values that meet the criteria, but I am fuzzy on how this all pieces together.![]()
When you use a conditional IF like this:
=IF((A2:A60="Site2")*(D2:D60="Pre"),B2:B60)
.....then you get the required values in the returned array....but also a bunch of FALSE values on rows where the conditions aren't satisfied.
For many functions, like SUM, AVERAGE or MEDIAN, for instance, that's not a problem because the Boolean values are simply ignored....but LINEST doesn't ignore Booleans or blanks so we need a way to return an array which only contains the required values.
To do that we can use this formula:
=INDEX(B2:B60,N(IF(1,MODE.MULT(IF((A2:A60="Site2")*(D2:D60="Pre"),(ROW(B2:B60)-ROW(B2)+1)*{1,1})))))
The IF function returns all the relative row values for the rows where the conditions are satisfied....and also some FALSE values, so with your data this part...
=IF((A2:A60="Site2")*(D2:D60="Pre"),(ROW(B2:B60)-ROW(B2)+1))
will result in this array:
Formula:
Please Login or Register to view this content.
....and we know that if we feed an array like that to MODE.MULT function then the result will be just the numbers without the Booleans..........but only for numbers that appear more than once, hence the {1,1} part which doubles up the above to give this array:
Formula:
Please Login or Register to view this content.
Now because each of the relative row numbers appear twice MODE.MULT will return them all as the most common modal values, i.e. this array:
{35;36;37;38;39;40;41;42;43;44;45;46;47;48;49;50;51;52;53;54;55;56;57;58}
We now want to feed that to INDEX function to get an array of the actual values from row B.....but INDEX is resistant to that, so you need this slightly convoluted setup to do that successfully
=INDEX(B2:B60,N(IF(1,array)))
so the result is just the numeric values from the required rows
This technique is courtesy of XOR LX, see an explanation here
Last edited by daddylonglegs; 11-19-2017 at 02:37 PM.
There are currently 1 users browsing this thread. (0 members and 1 guests)
Bookmarks