Home |
Search |
Today's Posts |
#1
![]() |
|||
|
|||
![]() Hello, I am working on converting a set of data from an old system to a new system, and in the process, I need to be able to do the index below, but to also add in one more critieria. I need it to not just return the result, but to return the result based on the max date, which is in a different column. =INDEX(Migration!$CH$2:$CH$3900,MATCH(1,(Migration !$A$2:$A$3900=A2)*(Migration!$B$2:$B$3900=B2),0)) Migration!$CH = Status column (open, closed, scheduled) Migration!$A = PO # Migration!$B = Job type (rough, trim) The last column needed to compare against is Migration!$CK I experimented with many options, including: =INDEX(MAX(Migration!$CK$2:$CK$3900)*Migration!$CH $2:$CH$3900,MATCH(1,(Migration!$A$2:$A$3900=A2)*(M igration!$B$2:$B$3900=B2),0)) But no luck. Any ideas? Would this be easier using VBA? Thank you, Kelly -- kkendall ------------------------------------------------------------------------ kkendall's Profile: http://www.excelforum.com/member.php...o&userid=25936 View this thread: http://www.excelforum.com/showthread...hreadid=393096 |
#2
![]() |
|||
|
|||
![]() Try... =INDEX(Migration!$CH$2:$CH$3900,MATCH(1,(Migration !$A$2:$A$3900=A2)*(Migration!$B$2:$B$3900=B2)*(Mig ration!$CK$2:$CK$3900=MAX(IF((Migration!$A$2:$A$39 00=A2)*(Migration!$B$2:$B$3900=B2),Migration!$CK$2 :$CK$3900))),0)) ...confirmed with CONTROL+SHIFT+ENTER, not just ENTER. Hope this helps! kkendall Wrote: Hello, I am working on converting a set of data from an old system to a new system, and in the process, I need to be able to do the index below, but to also add in one more critieria. I need it to not just return the result, but to return the result based on the max date, which is in a different column. =INDEX(Migration!$CH$2:$CH$3900,MATCH(1,(Migration !$A$2:$A$3900=A2)*(Migration!$B$2:$B$3900=B2),0)) Migration!$CH = Status column (open, closed, scheduled) Migration!$A = PO # Migration!$B = Job type (rough, trim) The last column needed to compare against is Migration!$CK which is a date column. I experimented with many options, including: =INDEX(MAX(Migration!$CK$2:$CK$3900)*Migration!$CH $2:$CH$3900,MATCH(1,(Migration!$A$2:$A$3900=A2)*(M igration!$B$2:$B$3900=B2),0)) I have also set the code, except for the last part I cannot figue out as: =INDEX(Migration!$A$3:$CK$3901,MATCH(1,(Migration! $A$3:$A$3901=A2)*(Migration!$B$3:$B$3901=F2),0),86 ) But no luck. Any ideas? Would this be easier using VBA? Thank you, Kelly -- Domenic ------------------------------------------------------------------------ Domenic's Profile: http://www.excelforum.com/member.php...o&userid=10785 View this thread: http://www.excelforum.com/showthread...hreadid=393096 |
#3
![]() |
|||
|
|||
![]() That worked perfect. Thank you very much for the help. Kelly -- kkendall ------------------------------------------------------------------------ kkendall's Profile: http://www.excelforum.com/member.php...o&userid=25936 View this thread: http://www.excelforum.com/showthread...hreadid=393096 |
#4
![]() |
|||
|
|||
![]() Domenic, thanks again for the help. I am on to my next and last issue with this formula. I need to use it in a different location to basically concatenate every entry that it finds, less the max data value. I hope that makes sense. So what I am trying to see is if I can add something to it less max-1, max-2, etc to pull each record in in order. Is that at all possible? Would it be something like: =INDEX(Migration!$CW$2:$CW$3900,MATCH(1,(Migration !$A$2:$A$3900=A2)*(Migration!$B$2:$B$3900=F2)*(Mig ration!$CK$2:$CK$3900=MAX(-1)*(IF((Migration!$A$2:$A$3900=A2)*(Migration!$B$2 :$B$3900=F2),Migration!$CK$2:$CK$3900))),0)) -- kkendall ------------------------------------------------------------------------ kkendall's Profile: http://www.excelforum.com/member.php...o&userid=25936 View this thread: http://www.excelforum.com/showthread...hreadid=393096 |
#5
![]() |
|||
|
|||
![]() To get the second largest, use the LARGE function with 2 as its position argument... =INDEX(Migration!$CW$2:$CW$3900,MATCH(1,(Migration !$A$2:$A$3900=A2)*(Migration!$B$2:$B$3900=B2)*(Mig ration!$CK$2:$CK$3900=LARGE(IF((Migration!$A$2:$A$ 3900=A2)*(Migration!$B$2:$B$3900=B2),Migration!$CK $2:$CK$3900),2)),0)) Actually, you can replace the last number 2 (position argument for LARGE) with ROWS($CY$2:CY2), enter the formula in CY2, and copy down. This will give you the first largest, second largest, third largest, etc. Hope this helps! kkendall Wrote: Domenic, thanks again for the help. I am on to my next and last issue with this formula. I need to use it in a different location to basically concatenate every entry that it finds, less the max data value. I hope that makes sense. So what I am trying to see is if I can add something to it less max-1, max-2, etc to pull each record in in order. Is that at all possible? Would it be something like: =INDEX(Migration!$CW$2:$CW$3900,MATCH(1,(Migration !$A$2:$A$3900=A2)*(Migration!$B$2:$B$3900=F2)*(Mig ration!$CK$2:$CK$3900=MAX(-1)*(IF((Migration!$A$2:$A$3900=A2)*(Migration!$B$2 :$B$3900=F2),Migration!$CK$2:$CK$3900))),0)) -- Domenic ------------------------------------------------------------------------ Domenic's Profile: http://www.excelforum.com/member.php...o&userid=10785 View this thread: http://www.excelforum.com/showthread...hreadid=393096 |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
cell color index comparison | New Users to Excel | |||
How to add in an array formula if iisna index match | Excel Worksheet Functions | |||
Formula to list unique values | Excel Worksheet Functions | |||
VBA Import of text file & Array parsing of that data | Excel Discussion (Misc queries) | |||
index to a range of cells | Excel Worksheet Functions |