VLookup or index/match help with date ranges in criteria

saboorsas

New Member
Joined
Aug 19, 2003
Messages
13
Book1
ABCDEFG
1Sales
2Sales NoProductPurchase DateSale DateSales ValuePurchase ValueMargin
31Baked Beans15/08/200616/08/20060
42Baked Beans15/08/200603/09/20060
53Salt Beef02/09/200615/09/20060
6
7
8Purchase Values
9ProductDate fromDate toValue
10Baked Beans01/08/200631/08/200610
11Macaroni01/07/200631/07/20062
12Salt Beef38,96130/09/200611
13
14
15Sales Values
16ProductDate fromDate toValue
17Baked Beans01/08/200631/08/200612
18Baked Beans01/09/200630/09/200617
19Salt Beef01/09/200630/09/200622
Sheet1


Umm, 3rd time lucky?

I have 2 sets of data from which I am trying to match information into a 3rd range (as demonstartated above). I'm familair with index/match as well a vlookup. My problem this time is that there are date ranges involved. Not too sure where to start.
Also, not too sure if this is releavnt place to post but, would this be easier done in Access?
 

Some videos you may like

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.

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
One way would be to use this formula in E3 copied down

=LOOKUP(2,1/((A$17:A$19=$B3)*(B$17:B$19<=$D3)*(C$17:C$19>=$D3)),D$17:D$19)

with a similar formula in F3
 

Krishnakumar

Well-known Member
Joined
Feb 28, 2003
Messages
2,615
Hi,

In E3,

=LOOKUP(2,1/(($A$17:$A$19=B3)*(D3>=$B$17:$B$19)*(D3<=$C$17:$C$19)),$D$17:$D$19)

F3,

=LOOKUP(2,1/(($A$10:$A$12=B3)*(C3>=$B$10:$B$12)*(C3<=$C$10:$C$12)),$D$10:$D$12)

HTH
 

saboorsas

New Member
Joined
Aug 19, 2003
Messages
13
I tried the formulae.

Many thanks. I'm trying to understand how the formula works. What is the significance of the following:

1/(($A$17:$A$19=B5)*(D5>=$B$17:$B$19)*(D5<=$C$17:$C$19))
 

Watch MrExcel Video

Forum statistics

Threads
1,114,061
Messages
5,545,763
Members
410,704
Latest member
Cobber2008
Top