Lookup value /="" and closest to a given date

deLockloire

Board Regular
Joined
Apr 4, 2008
Messages
110
Office Version
  1. 365
Platform
  1. Windows
Hi,

I have a table. Dates in Column A, values in Column B. I need to lookup the last data from column B for a date given but only if the value is not "" (I populate column B with a formula, and if that formula doesn't find anything, it returns a ""). If there is no data in Column B for the date given, I need the last data which is not "", closest to but less than the date given.

I'm putting this into a cell with a multilayered conditional formula, so I'm just curious what would be the shortest solution to keep the already complex formula as simple as possible.

best,
deL
 
DateValue DateFirst ValueLast Value
6/25/2012229.97 7/1/2012229.13240.75
6/26/2012229.72 6/26/2012229.72229.72
6/27/2012228.97
6/28/2012231.62
6/29/2012229.13
6/29/2012240.75
6/30/2012
7/1/2012
7/2/2012225.91

<colgroup><col style="width: 86pt; mso-width-source: userset; mso-width-alt: 4067;" width="114"> <col style="width: 62pt; mso-width-source: userset; mso-width-alt: 2958;" width="83"> <col style="width: 48pt;" span="2" width="64"> <col style="width: 53pt; mso-width-source: userset; mso-width-alt: 2531;" width="71"> <col style="width: 67pt; mso-width-source: userset; mso-width-alt: 3157;" width="89"> <col style="width: 64pt; mso-width-source: userset; mso-width-alt: 3043;" width="86"> <tbody>
</tbody>

Define BigNum as referring to:

=9.99999999999999E+307

F2, control+shift+enter, not just enter, and copy down:
Rich (BB code):
=INDEX($B$2:$B$10,MATCH(MIN(ABS(IF(ISNUMBER($B$2:$B$10),
  IF($A$2:$A$10<=E2,$A$2:$A$10-E2,BigNum),BigNum))),
   ABS(IF(ISNUMBER($B$2:$B$10),IF($A$2:$A$10<=E2,$A$2:$A$10-E2,BigNum),
    BigNum)),0))

If we introduce the V() function, we can avoid computing twice...
Rich (BB code):
=INDEX($B$2:$B$10,MATCH(MIN(v(ABS(IF(ISNUMBER($B$2:$B$10),
  IF($A$2:$A$10<=E2,$A$2:$A$10-E2,BigNum),BigNum)))),v(),0))

You need to add the following code for () as a module to your workbook:

Public Function V(Optional vrnt As Variant) As Variant
'
' Stephen
Dunn
' 2002-09-12
'
Static vrntV As Variant
If Not IsMissing(vrnt) Then vrntV = vrnt
V = vrntV
End Function
 
Upvote 0

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.

Forum statistics

Threads
1,213,562
Messages
6,114,322
Members
448,564
Latest member
ED38

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