Find nearest value in a column based on a criteria

uttamsaxena

Board Regular
Joined
Apr 22, 2003
Messages
182
I have a table to find a data value. In one cell A1 a number between 1 to 15 is selected and in another cell A2 a value is typed. Suppose A1 = 14 and A2 = 176482.

Now the objective is to find the exact or next higher value as given in A2 in the column with top row value 14 form the table. Here Column with header 14 don't have exact value as in A2. So It must output next higher value in column 14 ie 177400 in output cell A3. Can one help with a formula for cell A3.

[TABLE="class: grid, width: 1167"]
<tbody>[TR]
[TD="align: right"]1[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]3[/TD]
[TD="align: right"]4[/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]6[/TD]
[TD="align: right"]7[/TD]
[TD="align: right"]8[/TD]
[TD="align: right"]9[/TD]
[TD="align: right"]10[/TD]
[TD="align: right"]11[/TD]
[TD="align: right"]12[/TD]
[TD="align: right"]13[/TD]
[TD="align: right"]14[/TD]
[TD="align: right"]15[/TD]
[/TR]
[TR]
[TD="align: right"]19900[/TD]
[TD="align: right"]1700[/TD]
[TD="align: right"]22400[/TD]
[TD="align: right"]27200[/TD]
[TD="align: right"]29800[/TD]
[TD="align: right"]36800[/TD]
[TD="align: right"]44900[/TD]
[TD="align: right"]47600[/TD]
[TD="align: right"]53100[/TD]
[TD="align: right"]56100[/TD]
[TD="align: right"]67700[/TD]
[TD="align: right"]123100[/TD]
[TD="align: right"]131100[/TD]
[TD="align: right"]144200[/TD]
[TD="align: right"]171400[/TD]
[/TR]
[TR]
[TD="align: right"]20500[/TD]
[TD="align: right"]1800[/TD]
[TD="align: right"]23100[/TD]
[TD="align: right"]28000[/TD]
[TD="align: right"]30700[/TD]
[TD="align: right"]37900[/TD]
[TD="align: right"]46200[/TD]
[TD="align: right"]49000[/TD]
[TD="align: right"]54700[/TD]
[TD="align: right"]57800[/TD]
[TD="align: right"]69700[/TD]
[TD="align: right"]126800[/TD]
[TD="align: right"]135000[/TD]
[TD="align: right"]148500[/TD]
[TD="align: right"]176500[/TD]
[/TR]
[TR]
[TD="align: right"]21100[/TD]
[TD="align: right"]1900[/TD]
[TD="align: right"]23800[/TD]
[TD="align: right"]28800[/TD]
[TD="align: right"]31600[/TD]
[TD="align: right"]39000[/TD]
[TD="align: right"]47600[/TD]
[TD="align: right"]50500[/TD]
[TD="align: right"]56300[/TD]
[TD="align: right"]59500[/TD]
[TD="align: right"]71800[/TD]
[TD="align: right"]130600[/TD]
[TD="align: right"]139100[/TD]
[TD="align: right"]153000[/TD]
[TD="align: right"]181800[/TD]
[/TR]
[TR]
[TD="align: right"]21700[/TD]
[TD="align: right"]2000[/TD]
[TD="align: right"]24500[/TD]
[TD="align: right"]29700[/TD]
[TD="align: right"]32500[/TD]
[TD="align: right"]40200[/TD]
[TD="align: right"]49000[/TD]
[TD="align: right"]52000[/TD]
[TD="align: right"]58000[/TD]
[TD="align: right"]61300[/TD]
[TD="align: right"]74000[/TD]
[TD="align: right"]134500[/TD]
[TD="align: right"]143300[/TD]
[TD="align: right"]157600[/TD]
[TD="align: right"]187300[/TD]
[/TR]
[TR]
[TD="align: right"]22400[/TD]
[TD="align: right"]2100[/TD]
[TD="align: right"]25200[/TD]
[TD="align: right"]30600[/TD]
[TD="align: right"]33500[/TD]
[TD="align: right"]41400[/TD]
[TD="align: right"]50500[/TD]
[TD="align: right"]53600[/TD]
[TD="align: right"]59700[/TD]
[TD="align: right"]63100[/TD]
[TD="align: right"]76200[/TD]
[TD="align: right"]138500[/TD]
[TD="align: right"]147600[/TD]
[TD="align: right"]162300[/TD]
[TD="align: right"]192900[/TD]
[/TR]
[TR]
[TD="align: right"]23100[/TD]
[TD="align: right"]2200[/TD]
[TD="align: right"]26000[/TD]
[TD="align: right"]31500[/TD]
[TD="align: right"]34500[/TD]
[TD="align: right"]42600[/TD]
[TD="align: right"]52000[/TD]
[TD="align: right"]55200[/TD]
[TD="align: right"]61500[/TD]
[TD="align: right"]65000[/TD]
[TD="align: right"]78500[/TD]
[TD="align: right"]142700[/TD]
[TD="align: right"]152000[/TD]
[TD="align: right"]167200[/TD]
[TD="align: right"]198700[/TD]
[/TR]
[TR]
[TD="align: right"]23800[/TD]
[TD="align: right"]2300[/TD]
[TD="align: right"]26800[/TD]
[TD="align: right"]32400[/TD]
[TD="align: right"]35500[/TD]
[TD="align: right"]43900[/TD]
[TD="align: right"]53600[/TD]
[TD="align: right"]56900[/TD]
[TD="align: right"]63300[/TD]
[TD="align: right"]67000[/TD]
[TD="align: right"]80900[/TD]
[TD="align: right"]147000[/TD]
[TD="align: right"]156600[/TD]
[TD="align: right"]172200[/TD]
[TD="align: right"]204700[/TD]
[/TR]
[TR]
[TD="align: right"]24500[/TD]
[TD="align: right"]2400[/TD]
[TD="align: right"]27600[/TD]
[TD="align: right"]33400[/TD]
[TD="align: right"]36600[/TD]
[TD="align: right"]45200[/TD]
[TD="align: right"]55200[/TD]
[TD="align: right"]58600[/TD]
[TD="align: right"]65200[/TD]
[TD="align: right"]69000[/TD]
[TD="align: right"]83300[/TD]
[TD="align: right"]151400[/TD]
[TD="align: right"]161300[/TD]
[TD="align: right"]177400[/TD]
[TD="align: right"]210800[/TD]
[/TR]
[TR]
[TD="align: right"]25200[/TD]
[TD="align: right"]2500[/TD]
[TD="align: right"]28400[/TD]
[TD="align: right"]34400[/TD]
[TD="align: right"]37700[/TD]
[TD="align: right"]46600[/TD]
[TD="align: right"]56900[/TD]
[TD="align: right"]60400[/TD]
[TD="align: right"]67200[/TD]
[TD="align: right"]71100[/TD]
[TD="align: right"]85800[/TD]
[TD="align: right"]155900[/TD]
[TD="align: right"]166100[/TD]
[TD="align: right"]182700[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]26000[/TD]
[TD="align: right"]2600[/TD]
[TD="align: right"]29300[/TD]
[TD="align: right"]35400[/TD]
[TD="align: right"]38800[/TD]
[TD="align: right"]48000[/TD]
[TD="align: right"]58600[/TD]
[TD="align: right"]62200[/TD]
[TD="align: right"]69200[/TD]
[TD="align: right"]73200[/TD]
[TD="align: right"]88400[/TD]
[TD="align: right"]160600[/TD]
[TD="align: right"]171100[/TD]
[TD="align: right"]188200[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]26800[/TD]
[TD="align: right"]2700[/TD]
[TD="align: right"]30200[/TD]
[TD="align: right"]36500[/TD]
[TD="align: right"]40000[/TD]
[TD="align: right"]49400[/TD]
[TD="align: right"]60400[/TD]
[TD="align: right"]64100[/TD]
[TD="align: right"]71300[/TD]
[TD="align: right"]75400[/TD]
[TD="align: right"]91100[/TD]
[TD="align: right"]165400[/TD]
[TD="align: right"]176200[/TD]
[TD="align: right"]193800[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]27600[/TD]
[TD="align: right"]2800[/TD]
[TD="align: right"]31100[/TD]
[TD="align: right"]37600[/TD]
[TD="align: right"]41200[/TD]
[TD="align: right"]50900[/TD]
[TD="align: right"]62200[/TD]
[TD="align: right"]66000[/TD]
[TD="align: right"]73400[/TD]
[TD="align: right"]77700[/TD]
[TD="align: right"]93800[/TD]
[TD="align: right"]170400[/TD]
[TD="align: right"]181500[/TD]
[TD="align: right"]199600[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]28400[/TD]
[TD="align: right"]2900[/TD]
[TD="align: right"]32000[/TD]
[TD="align: right"]38700[/TD]
[TD="align: right"]42400[/TD]
[TD="align: right"]52400[/TD]
[TD="align: right"]64100[/TD]
[TD="align: right"]68000[/TD]
[TD="align: right"]75600[/TD]
[TD="align: right"]80000[/TD]
[TD="align: right"]96600[/TD]
[TD="align: right"]175500[/TD]
[TD="align: right"]186900[/TD]
[TD="align: right"]205600[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]29300[/TD]
[TD="align: right"]3000[/TD]
[TD="align: right"]33000[/TD]
[TD="align: right"]39900[/TD]
[TD="align: right"]43700[/TD]
[TD="align: right"]54000[/TD]
[TD="align: right"]66000[/TD]
[TD="align: right"]70000[/TD]
[TD="align: right"]77900[/TD]
[TD="align: right"]82400[/TD]
[TD="align: right"]99500[/TD]
[TD="align: right"]180800[/TD]
[TD="align: right"]192500[/TD]
[TD="align: right"]211800[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]30200[/TD]
[TD="align: right"]3100[/TD]
[TD="align: right"]34000[/TD]
[TD="align: right"]41100[/TD]
[TD="align: right"]45000[/TD]
[TD="align: right"]55600[/TD]
[TD="align: right"]68000[/TD]
[TD="align: right"]72100[/TD]
[TD="align: right"]80200[/TD]
[TD="align: right"]84900[/TD]
[TD="align: right"]102500[/TD]
[TD="align: right"]186200[/TD]
[TD="align: right"]198300[/TD]
[TD="align: right"]218200[/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]31100[/TD]
[TD="align: right"]3200[/TD]
[TD="align: right"]35000[/TD]
[TD="align: right"]42300[/TD]
[TD="align: right"]46400[/TD]
[TD="align: right"]57300[/TD]
[TD="align: right"]70000[/TD]
[TD="align: right"]74300[/TD]
[TD="align: right"]82600[/TD]
[TD="align: right"]87400[/TD]
[TD="align: right"]105600[/TD]
[TD="align: right"]191800[/TD]
[TD="align: right"]204200[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]32000[/TD]
[TD="align: right"]3300[/TD]
[TD="align: right"]36100[/TD]
[TD="align: right"]43600[/TD]
[TD="align: right"]47800[/TD]
[TD="align: right"]59000[/TD]
[TD="align: right"]72100[/TD]
[TD="align: right"]76500[/TD]
[TD="align: right"]85100[/TD]
[TD="align: right"]90000[/TD]
[TD="align: right"]108800[/TD]
[TD="align: right"]197600[/TD]
[TD="align: right"]210300[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]33000[/TD]
[TD="align: right"]3400[/TD]
[TD="align: right"]37200[/TD]
[TD="align: right"]44900[/TD]
[TD="align: right"]49200[/TD]
[TD="align: right"]60800[/TD]
[TD="align: right"]74300[/TD]
[TD="align: right"]78800[/TD]
[TD="align: right"]87700[/TD]
[TD="align: right"]92700[/TD]
[TD="align: right"]112100[/TD]
[TD="align: right"]203500[/TD]
[TD="align: right"]216600[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]34000[/TD]
[TD="align: right"]3500[/TD]
[TD="align: right"]38300[/TD]
[TD="align: right"]46200[/TD]
[TD="align: right"]50700[/TD]
[TD="align: right"]62600[/TD]
[TD="align: right"]76500[/TD]
[TD="align: right"]81200[/TD]
[TD="align: right"]90300[/TD]
[TD="align: right"]95500[/TD]
[TD="align: right"]115500[/TD]
[TD="align: right"]209600[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]35000[/TD]
[TD="align: right"]3600[/TD]
[TD="align: right"]39400[/TD]
[TD="align: right"]47600[/TD]
[TD="align: right"]52200[/TD]
[TD="align: right"]64500[/TD]
[TD="align: right"]78800[/TD]
[TD="align: right"]83600[/TD]
[TD="align: right"]93000[/TD]
[TD="align: right"]98400[/TD]
[TD="align: right"]119000[/TD]
[TD="align: right"]215900[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]36100[/TD]
[TD="align: right"]3700[/TD]
[TD="align: right"]40600[/TD]
[TD="align: right"]49000[/TD]
[TD="align: right"]53800[/TD]
[TD="align: right"]66400[/TD]
[TD="align: right"]81200[/TD]
[TD="align: right"]86100[/TD]
[TD="align: right"]95800[/TD]
[TD="align: right"]101400[/TD]
[TD="align: right"]122600[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]37200[/TD]
[TD="align: right"]3800[/TD]
[TD="align: right"]41800[/TD]
[TD="align: right"]50500[/TD]
[TD="align: right"]55400[/TD]
[TD="align: right"]68400[/TD]
[TD="align: right"]83600[/TD]
[TD="align: right"]88700[/TD]
[TD="align: right"]98700[/TD]
[TD="align: right"]104400[/TD]
[TD="align: right"]126300[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]38300[/TD]
[TD="align: right"]3900[/TD]
[TD="align: right"]43100[/TD]
[TD="align: right"]52000[/TD]
[TD="align: right"]57100[/TD]
[TD="align: right"]70500[/TD]
[TD="align: right"]86100[/TD]
[TD="align: right"]91400[/TD]
[TD="align: right"]101700[/TD]
[TD="align: right"]107500[/TD]
[TD="align: right"]130100[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]39400[/TD]
[TD="align: right"]4000[/TD]
[TD="align: right"]44400[/TD]
[TD="align: right"]53600[/TD]
[TD="align: right"]58800[/TD]
[TD="align: right"]72600[/TD]
[TD="align: right"]88700[/TD]
[TD="align: right"]94100[/TD]
[TD="align: right"]104800[/TD]
[TD="align: right"]110700[/TD]
[TD="align: right"]134000[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]40600[/TD]
[TD="align: right"]4100[/TD]
[TD="align: right"]45700[/TD]
[TD="align: right"]55200[/TD]
[TD="align: right"]60600[/TD]
[TD="align: right"]74800[/TD]
[TD="align: right"]91400[/TD]
[TD="align: right"]96900[/TD]
[TD="align: right"]107900[/TD]
[TD="align: right"]114000[/TD]
[TD="align: right"]138000[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]41800[/TD]
[TD="align: right"]4200[/TD]
[TD="align: right"]47100[/TD]
[TD="align: right"]56900[/TD]
[TD="align: right"]62400[/TD]
[TD="align: right"]77000[/TD]
[TD="align: right"]94100[/TD]
[TD="align: right"]99800[/TD]
[TD="align: right"]111100[/TD]
[TD="align: right"]117400[/TD]
[TD="align: right"]142100[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]43100[/TD]
[TD="align: right"]4300[/TD]
[TD="align: right"]48500[/TD]
[TD="align: right"]58600[/TD]
[TD="align: right"]64300[/TD]
[TD="align: right"]79300[/TD]
[TD="align: right"]96900[/TD]
[TD="align: right"]102800[/TD]
[TD="align: right"]114400[/TD]
[TD="align: right"]120900[/TD]
[TD="align: right"]146400[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]44400[/TD]
[TD="align: right"]4400[/TD]
[TD="align: right"]50000[/TD]
[TD="align: right"]60400[/TD]
[TD="align: right"]66200[/TD]
[TD="align: right"]81700[/TD]
[TD="align: right"]99800[/TD]
[TD="align: right"]105900[/TD]
[TD="align: right"]117800[/TD]
[TD="align: right"]124500[/TD]
[TD="align: right"]150800[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]45700[/TD]
[TD="align: right"]4500[/TD]
[TD="align: right"]51500[/TD]
[TD="align: right"]62200[/TD]
[TD="align: right"]68200[/TD]
[TD="align: right"]84200[/TD]
[TD="align: right"]102800[/TD]
[TD="align: right"]109100[/TD]
[TD="align: right"]121300[/TD]
[TD="align: right"]128200[/TD]
[TD="align: right"]155300[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]47100[/TD]
[TD="align: right"]4600[/TD]
[TD="align: right"]53000[/TD]
[TD="align: right"]64100[/TD]
[TD="align: right"]70200[/TD]
[TD="align: right"]86700[/TD]
[TD="align: right"]105900[/TD]
[TD="align: right"]112400[/TD]
[TD="align: right"]124900[/TD]
[TD="align: right"]132000[/TD]
[TD="align: right"]160000[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]48500[/TD]
[TD="align: right"]4700[/TD]
[TD="align: right"]54600[/TD]
[TD="align: right"]66000[/TD]
[TD="align: right"]72300[/TD]
[TD="align: right"]89300[/TD]
[TD="align: right"]109100[/TD]
[TD="align: right"]115800[/TD]
[TD="align: right"]128600[/TD]
[TD="align: right"]136000[/TD]
[TD="align: right"]164800[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]50000[/TD]
[TD="align: right"]4800[/TD]
[TD="align: right"]56200[/TD]
[TD="align: right"]68000[/TD]
[TD="align: right"]74500[/TD]
[TD="align: right"]92000[/TD]
[TD="align: right"]112400[/TD]
[TD="align: right"]119300[/TD]
[TD="align: right"]132500[/TD]
[TD="align: right"]140100[/TD]
[TD="align: right"]169700[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]51500[/TD]
[TD="align: right"]4900[/TD]
[TD="align: right"]57900[/TD]
[TD="align: right"]70000[/TD]
[TD="align: right"]76700[/TD]
[TD="align: right"]94800[/TD]
[TD="align: right"]115800[/TD]
[TD="align: right"]122900[/TD]
[TD="align: right"]136500[/TD]
[TD="align: right"]144300[/TD]
[TD="align: right"]174800[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]53000[/TD]
[TD="align: right"]5000[/TD]
[TD="align: right"]59600[/TD]
[TD="align: right"]72100[/TD]
[TD="align: right"]79000[/TD]
[TD="align: right"]97600[/TD]
[TD="align: right"]119300[/TD]
[TD="align: right"]126600[/TD]
[TD="align: right"]140600[/TD]
[TD="align: right"]148600[/TD]
[TD="align: right"]180000[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]54600[/TD]
[TD="align: right"]5200[/TD]
[TD="align: right"]61400[/TD]
[TD="align: right"]74300[/TD]
[TD="align: right"]81400[/TD]
[TD="align: right"]100500[/TD]
[TD="align: right"]122900[/TD]
[TD="align: right"]130400[/TD]
[TD="align: right"]144800[/TD]
[TD="align: right"]153100[/TD]
[TD="align: right"]185400[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]56200[/TD]
[TD="align: right"]5400[/TD]
[TD="align: right"]63200[/TD]
[TD="align: right"]76500[/TD]
[TD="align: right"]83800[/TD]
[TD="align: right"]103500[/TD]
[TD="align: right"]126600[/TD]
[TD="align: right"]134300[/TD]
[TD="align: right"]149100[/TD]
[TD="align: right"]157700[/TD]
[TD="align: right"]191000[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]57900[/TD]
[TD="align: right"]5600[/TD]
[TD="align: right"]65100[/TD]
[TD="align: right"]78800[/TD]
[TD="align: right"]86300[/TD]
[TD="align: right"]106600[/TD]
[TD="align: right"]130400[/TD]
[TD="align: right"]138300[/TD]
[TD="align: right"]153600[/TD]
[TD="align: right"]162400[/TD]
[TD="align: right"]196700[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]59600[/TD]
[TD="align: right"]5800[/TD]
[TD="align: right"]67100[/TD]
[TD="align: right"]81200[/TD]
[TD="align: right"]88900[/TD]
[TD="align: right"]109800[/TD]
[TD="align: right"]134300[/TD]
[TD="align: right"]142400[/TD]
[TD="align: right"]158200[/TD]
[TD="align: right"]167300[/TD]
[TD="align: right"]202600[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]61400[/TD]
[TD="align: right"]6000[/TD]
[TD="align: right"]69100[/TD]
[TD="align: right"]83600[/TD]
[TD="align: right"]91600[/TD]
[TD="align: right"]113100[/TD]
[TD="align: right"]138300[/TD]
[TD="align: right"]146700[/TD]
[TD="align: right"]162900[/TD]
[TD="align: right"]172300[/TD]
[TD="align: right"]208700[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]63200[/TD]
[TD="align: right"]6200[/TD]
[TD="align: right"]71200[/TD]
[TD="align: right"]86100[/TD]
[TD="align: right"]94300[/TD]
[TD="align: right"]116500[/TD]
[TD="align: right"]142400[/TD]
[TD="align: right"]151100[/TD]
[TD="align: right"]167800[/TD]
[TD="align: right"]177500[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
hi,

Considering your data is in range (A5:O44) use following array formula in Cell A3

=MIN(IF((((A4:O4=$A$1)*(A5:O44)<>0)+((A5:O44)>=$A$2))=2,(A5:O44),"False"))

Please Press Ctrl+Shift+Enter and not only Enter.

One point to highlight is there is the output comes as Zero (0) , please note that there is no value in the provided column which matches given criteria.

Thanks

Swapnil Shah
 
Upvote 0
I have a table to find a data value. In one cell A1 a number between 1 to 15 is selected and in another cell A2 a value is typed. Suppose A1 = 14 and A2 = 176482.

Now the objective is to find the exact or next higher value as given in A2 in the column with top row value 14 form the table. Here Column with header 14 don't have exact value as in A2. So It must output next higher value in column 14 ie 177400 in output cell A3. Can one help with a formula for cell A3.

[...]

Let A1:O41 of Sheet1 house the data.

A1 of Sheet2 houses a relative column indicator like 14.

A2 of Sheet2 houses a look up value like 176482.

In A3 of Sheet2 enter:

=INDEX(Sheet1!$A$2:$O$41,MATCH(A2,INDEX(Sheet1!$A$2:$O$41,0,A1),1)+(VLOOKUP(A2,INDEX(Sheet1!$A$1:$O$41,0,MATCH(A1,INDEX(Sheet1!$A$1:$O$41,1,0),0)),1,1) < A2),A1)
 
Upvote 0
hi,

Considering your data is in range (A5:O44) use following array formula in Cell A3

=MIN(IF((((A4:O4=$A$1)*(A5:O44)<>0)+((A5:O44)>=$A$2))=2,(A5:O44),"False"))

Please Press Ctrl+Shift+Enter and not only Enter.

One point to highlight is there is the output comes as Zero (0) , please note that there is no value in the provided column which matches given criteria.

Thanks

Swapnil Shah

Thanks for your help but somehow it is returning zero with the given example.
 
Upvote 0
Let A1:O41 of Sheet1 house the data.

A1 of Sheet2 houses a relative column indicator like 14.

A2 of Sheet2 houses a look up value like 176482.

In A3 of Sheet2 enter:

=INDEX(Sheet1!$A$2:$O$41,MATCH(A2,INDEX(Sheet1!$A$2:$O$41,0,A1),1)+(VLOOKUP(A2,INDEX(Sheet1!$A$1:$O$41,0,MATCH(A1,INDEX(Sheet1!$A$1:$O$41,1,0),0)),1,1) < A2),A1)
Thanks Aladin, it is working perfectly.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,178
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top