Lookup a value from a range of dates in excel

janilee cantillas

New Member
Joined
Jun 29, 2013
Messages
2
I have two tables. A list of accounts and the other is a change log. I need to add a new column in table 1 where the value is the amount in table 2 for the correct account and correct validity period.

Please help
 

Some videos you may like

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Example:

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">Account</td><td style=";">Start</td><td style=";">End</td><td style=";">Amount</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">1</td><td style="text-align: right;;">January 1, 2012</td><td style="text-align: right;;">January 31, 2012</td><td style="text-align: right;;">30</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">2</td><td style="text-align: right;;">January 12, 2012</td><td style="text-align: right;;">February 12, 2012</td><td style="text-align: right;;">#N/A</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></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">Account</td><td style=";">Amount</td><td style=";">Start</td><td style=";">End</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">1</td><td style="text-align: right;;">10</td><td style="text-align: right;;">January 1, 2009</td><td style="text-align: right;;">December 5, 2010</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;">1</td><td style="text-align: right;;">20</td><td style="text-align: right;;">December 6, 2010</td><td style="text-align: right;;">June 1, 2011</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;">1</td><td style="text-align: right;;">30</td><td style="text-align: right;;">June 2, 2011</td><td style="text-align: right;;">December 1, 2012</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;">2</td><td style="text-align: right;;">13</td><td style="text-align: right;;">January 15, 2011</td><td style="text-align: right;;">December 15, 2011</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: right;;">2</td><td style="text-align: right;;">20</td><td style="text-align: right;;">December 16, 2011</td><td style="text-align: right;;">February 10, 2012</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 #BBB;border-top:none;text-align: center;background-color: #DAE7F5;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: #BBB"><thead><tr style=" background-color: #DAE7F5;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: #DAE7F5;color: #161120">D2</th><td style="text-align:left">=INDEX(<font color="Blue">B$6:B$10,MATCH(<font color="Red">1,INDEX(<font color="Green">(<font color="Purple">A$6:A$10=A2</font>)*(<font color="Purple">C$6:C$10<=B2</font>)*(<font color="Purple">D$6:D$10>=C2</font>),</font>),FALSE</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">D3</th><td style="text-align:left">=INDEX(<font color="Blue">B$6:B$10,MATCH(<font color="Red">1,INDEX(<font color="Green">(<font color="Purple">A$6:A$10=A3</font>)*(<font color="Purple">C$6:C$10<=B3</font>)*(<font color="Purple">D$6:D$10>=C3</font>),</font>),FALSE</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 

janilee cantillas

New Member
Joined
Jun 29, 2013
Messages
2
Hi Andrew,

Thanks for this. Not sure why I can't match some of the formula...date is within the correct range..may i know what 1 in (match(1, index...) means? thanks.
 

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Can you give some examples that don't work as expected? Multiplying booleans returns 1 or 0. Match returns the relative position of the first 1.
 

Watch MrExcel Video

Forum statistics

Threads
1,102,894
Messages
5,489,567
Members
407,700
Latest member
SimpleJuan

This Week's Hot Topics

  • Timer in VBA - Stop, Start, Pause and Reset
    [CODE=vba][/CODE] Option Explicit Dim CmdStop As Boolean Dim Paused As Boolean Dim Start Dim TimerValue As Date Dim pausedTime As Date Sub...
  • how to updates multiple rows in muliselect listbox
    Hello everyone. I need help with below code. code is only chaning 1st row in mulitiselect list box. i know issue with code...
  • Delete Row from Table
    I am trying to delete a row from a table using VBA using a named range to find what I need to delete. My Range is finding the right cell. In the...
  • Assigning to a variable
    I have a for each block where I want to assign the value in column 5 of the found row to the variable Serv. [CODE=vba] For Each ws In...
  • Way to verify information
    Hi All, I don't know what to call this formula, and therefore can't search. I have a spreadsheet with information I want to reference...
  • Active Cell Address – Inactive Sheet
    How to use VBA to get the cell address of the active cell in an inactive worksheet and then place that cell address in a location on the current...
Top