Lookup or match dates from multiple columns and get data from same row/range

bgill

New Member
Joined
Aug 22, 2002
Messages
33
I have 3 years of data and I need to find the count and cost for the date that matches a date entered in a table. The date could be from any of the 3 years but I need to get the count from the table.

Sample data...
Column
A B C D E F G H I
DATE COUNT COST DATE COUNT COST DATE COUNT COST 1/1/11 5 $50 1/1/10 4 $60 1/1/09 3 $70
1/2/11 10 $100 1/2/10 9 $90 1/2/09 8 $80

I can't get vlookup to work with data in multiple columns. I can't figure out how to use sumproduct since I don't know what column the match witll be in.

Any help would be appreciated!

Becky
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
so using your data what would your results be?
Excel Workbook
ABCDEFGHI
1DATECOUNTCOSTDATECOUNTCOSTDATECOUNTCOST
21/1/20115$501/1/20104$601/1/20093$70
31/2/201110$1001/2/20109$901/2/20098$80
Sheet1
Excel 2003
 
Upvote 0
I need to look up both the count and the cost. So as an example, if I entered 1/2/2009 in a reference cell I would need the formula to give me back the count (8) in one cell. I would need to replicate the formula to give me the cost for the same date ($80).

Does that clarify?
 
Upvote 0
does this work
Excel Workbook
AB
1dateCount
21/1/20093
Sheet2
Excel 2003
Cell Formulas
RangeFormula
B2=IF(ISNUMBER(MATCH(A2,Sheet1!$D$2:$D$3,0)),INDEX(Sheet1!$E$2:$E$3,MATCH(A2,Sheet1!$D$2:$D$3,0),1), IF(ISNUMBER(MATCH(A2,Sheet1!$A$2:$A$3,0)),INDEX(Sheet1!$B$2:$B$3,MATCH(A2,Sheet1!$A$2:$A$3,0),1), IF(ISNUMBER(MATCH(A2,Sheet1!$G$2:$G$3,0)),INDEX(Sheet1!$H$2:$H$3,MATCH(A2,Sheet1!$G$2:$G$3,0),1))))
 
Upvote 0
Try;

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th><th>J</th><th>K</th><th>L</th><th>M</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td><td style="text-align: right;;"></td><td style=";">Which Row?</td><td style="text-align: right;;">3</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">1/1/2011</td><td style="text-align: right;;">5</td><td style="text-align: right;;">$50 </td><td style="text-align: right;;">1/1/2010</td><td style="text-align: right;;">4</td><td style="text-align: right;;">$60 </td><td style="text-align: right;;">1/1/2009</td><td style="text-align: right;;">3</td><td style="text-align: right;;">$70 </td><td style="text-align: right;;"></td><td style=";">Which Column?</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">1/2/2011</td><td style="text-align: right;;">10</td><td style="text-align: right;;">$100 </td><td style="text-align: right;;">1/2/2010</td><td style="text-align: right;;">9</td><td style="text-align: right;;">$90 </td><td style="text-align: right;;">1/2/2009</td><td style="text-align: right;;">8</td><td style="text-align: right;;">$80 </td><td style="text-align: right;;"></td><td style=";">Lookup Date</td><td style="text-align: right;;">1/2/2009</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">1/2/2009</td><td style="text-align: right;;">8</td><td style="text-align: right;;">80</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">K6</th><td style="text-align:left">=L3</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">L6</th><td style="text-align:left">=INDEX(<font color="Blue">A1:I1100,L1,L2+1</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">M6</th><td style="text-align:left">=INDEX(<font color="Blue">A1:I1100,L1,L2+2</font>)</td></tr></tbody></table></td></tr></table><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">L1</th><td style="text-align:left">{=SMALL(<font color="Blue">IF(<font color="Red">A2:I1000=L3,ROW(<font color="Green">A2:I1000</font>)</font>),1</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">L2</th><td style="text-align:left">{=SMALL(<font color="Blue">IF(<font color="Red">A2:I1000=L3,COLUMN(<font color="Green">A2:I1000</font>)</font>),1</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
 
Upvote 0

Forum statistics

Threads
1,224,586
Messages
6,179,719
Members
452,939
Latest member
WCrawford

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