Lookup and Find a value from a date range

Pumba

New Member
Joined
Nov 27, 2007
Messages
19
Hi There

I have a list of various exchange rates by currency and want to find where my transaction meets the exchange rate criteria. The data is as follows:

Currency Start Date of rate Exchange Rate
GBP 116.6
GBP 01/03/2011 117.321
GBP 01/04/2011 114
GBP 01/05/2011 115
GBP 01/06/2011 116
CAD 73.26
CAD 01/03/2011 74.32
CAD 18/04/2011 80


I then have a transaction which occurs on 05/05/20011 in the currency of GBP so it should pick up the exchange rate of 115. All my records have one blank value in the start date symbolising the start of the exchange rate.

I can pick up GBP by using a VLookup but how do I then tell it to pick up the date based upon a range found in my exchange rate table combined with the fact there is one blank value as default.

Thanks
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Assuming your data is in the range A2:C9, F1 = "GBP", F2 = 05/05/11, use the following formula, confirmed with ctrl+shift+enter:

PHP:
=SUMPRODUCT(--(A2:A9=F1),--(B2:B9=MAX(IF(A2:A9=F1,IF(B2:B9<F2,B2:B9)))),--(C2:C9))
 
Upvote 0
If you prefer to avoid a CSE formula you could use
=SUMPRODUCT(--(A2:A9=F1),--(B2:B9 >(F2-DAY(F2))),--(B2:B9<= EOMONTH(F2,0)),--(C2:C9))
 
Upvote 0

Forum statistics

Threads
1,224,595
Messages
6,179,798
Members
452,943
Latest member
Newbie4296

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