On 27 Nov 2015 at 11:11, Brian Barker wrote:
Date sent:Fri, 27 Nov 2015 11:11:17 +0000 To:users@global.libreoffice.org From:Brian barkerb.m.bar...@btinternet.com Subject:Re: [libreoffice-users] How to return cell address/reference instead of function result with 2d operations? At 03:56 27/11/2015 -0500, Edwar Cifuentes wrote: On 11/26/2015 09:26 AM, Tom Webb wrote: On 2015-11-25 17:26, Edwar Cifuentes wrote: When using functions like MAX on a 2d range how can I get the cell's address/reference returned instead of the result value? e.g. if I have this table starting at A1... 123 456 How can I get ... C2 Instead of ... 6 I know I could something containing MATCH if it were just a single row or column but here I have a table spanning several rows and columns and there seems to be no equivalent of MATCH for these situations. The following will find the address of the Max value. If there are duplicate values it shows the last location. =ADDRESS(MAX((A1:C2=MAX(A1:C2))*ROW(A1:C2)),MAX((A1:C2=MAX(A1:C2))*COLUMN(A1:C2)),4) This is an array function and you need to use Ctrl-Shift-Enter instead of Enter. Hey, this works! Sadly, I don't think it does. If the largest value happens to be duplicated in different rows and columns, the formula generates the address of neither but instead that of the intersection of that row and that column. Try changing either B1 or A2 to 7: for such separate changes the formula works. But now change both B1 and A2 to 7: the formula generates neither B1 nor A2 but B2 - which is not either of the cells containing the equal largest values. I need to analyse slowly and thoroughly but there's a part I can't get into my head right from the start: A1:C2=MAX(A1:C2)- what's that equal sign doing there? what does this part mean? It's Boolean expression, giving the result TRUE or FALSE. It's testing the individual cells in the range A1:C2 to determine whether they are equal to the maximum value of that range. It may seem strange to be able to write such an expression for an entire range instead of for individual cells, but that is the power of array formulae. In my testing, I didn't see that, it appears to result with the last one highest values. I did come up with a solution that handles duplicate hi values, and also handles duplicates. If one uses conditional formatting, one can use the condition of max(range) and change background color or other formatting,and it will highlight all the cell. Don't know if there was a need to get the address or just to highlight i. Also, had come up with a better method of my earlier one, but it doesn't handle duplicate max values. =ADDRESS(IF(MAX(A1:C2)=MAX(A1:C1),1,2),IF(MAX(A1:C2)=MAX(A1:A2),1,IF(MAX(A1:C2)=MAX(B1:B2),2,3)),4) That works if the range starts in a1. Did another test with range in another location, and it required more coding to get the correct cell address. =ADDRESS(IF(I9=MAX(I5:L5),1,IF(I9=MAX(I6:L6),2,3))+ROW(I5)-1,IF(I9=MAX(I5:I7),1,IF(I9=MAX(J5:J7),2,IF(I9=MAX(K4:K7),3,4)))+COLUMN(I5:I5)-1,4) Brian Barker -- To unsubscribe e-mail to: users+unsubscr...@global.libreoffice.org Problems? http://www.libreoffice.org/get-help/mailing-lists/how-to-unsubscribe/ Posting guidelines + more: http://wiki.documentfoundation.org/Netiquette List archive: http://listarchives.libreoffice.org/global/users/ All messages sent to this list will be publicly archived and cannot be deleted -- To unsubscribe e-mail to: users+unsubscr...@global.libreoffice.org Problems? http://www.libreoffice.org/get-help/mailing-lists/how-to-unsubscribe/ Posting guidelines + more: http://wiki.documentfoundation.org/Netiquette List archive: http://listarchives.libreoffice.org/global/users/ All messages sent to this list will be publicly archived and cannot be deleted