Conditional Lookup?

uberathlete

Board Regular
Joined
Jul 11, 2007
Messages
117
Hi everyone, I really need some help. Here's the situation (please refer to image):

6c3397p.jpg



Basically, I would like to fill column F. The values in column F2 must be those prices that occured at 8:25:00 on the corresponding date specified in column E. However, when there is no 8:25:00 price , then the last price of the previous date must be used instead and this value should be highlighted.

So in this case, cell F requires the 8:25:00 price on January 1, 2000 which would be 78.45 coming from cell C3. For cell F4, there is no 8:25:00 price on January 5, 2000 so instead it should have the last price of the previous date which is 77.89 and must be highlighted as well.

The result should then be like this:

4kvg2vq.gif


Anyone know how I could do this? Any suggestions would be greatly appreciated. Thank you!
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
Since the data is sorted by date and time, in ascending order, try the following...

Insert > Name > Define

Name: BigNum

Refers to:

=9.99999999999999E+307

Click Ok

Then try...

F2, copied down:

=LOOKUP(BigNum,CHOOSE({1,2},INDEX($C$2:$C$14,MATCH(E2-1,$A$2:$A$14)),VLOOKUP("8:25:00"+0,INDEX($B$2:$B$14,MATCH(E2,$A$2:$A$14,0)):INDEX($C$2:$C$14,MATCH(E2,$A$2:$A$14)),2,0)))

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,560
Members
449,089
Latest member
Motoracer88

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