vlookup with dates?

Ian1976

Board Regular
Joined
Feb 4, 2016
Messages
139
Office Version
  1. 365
Platform
  1. Windows
[TABLE="class: outer_border, width: 550, align: center"]
<tbody>[TR]
[TD="align: center"]U
[/TD]
[TD="align: center"]V
[/TD]
[TD="align: center"]W
[/TD]
[TD="align: center"]X
[/TD]
[TD="align: center"]Y
[/TD]
[TD="align: center"]Z
[/TD]
[TD="align: center"]AA
[/TD]
[/TR]
[TR]
[TD]6-Nov-18
[/TD]
[TD]7-Nov-18
[/TD]
[TD]8-Nov-18
[/TD]
[TD]9-Nov-18
[/TD]
[TD]10-Nov-18
[/TD]
[TD]11-Nov-8
[/TD]
[TD]12-Nov-18
[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
Hi all,

not sure its possible but I have "A" column with serial numbers in 123456 and column "O" with dates in, what I'm trying to do is when I sort them in to date order I'd like it to populate a table like this...If the date in column O matches the date on the table in column U then paste in the related serial number, also any suggestion on what I can do if I have 2 dates the same?

Thanks
Ian

Column A Column O
123456 6-Nov-18
654321 8-Nov-18
456123 10-Nov-18
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
Hi Ian,

Enter this as below, then drag across your dates then down as far as what you need;


Book1
AO
1SerialDates
21234566/11/2018
31234576/11/2018
41234588/11/2018
51234599/11/2018
612346010/11/2018
712346110/11/2018
81234628/11/2018
91234637/11/2018
1012346412/11/2018
1112346512/11/2018
Sheet1



Book1
UVWXYZAA
106-Nov-1807-Nov-1808-Nov-1809-Nov-1810-Nov-1811-Nov-1812-Nov-18
2123456123463123458123459123460123464
3123457123462123461123465
Sheet1
Cell Formulas
RangeFormula
U2{=IFERROR(INDEX($A$2:$A$11,SMALL(IF($O$2:$O$11=U$1,ROW($O$2:$O$11)-ROW($O$2)+1),ROWS(U$2:U2))),"")}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Last edited:
Upvote 0
Hi RasGhul,

That is just what i'm after, and works perfectly, although - the column "O" has formula in it not a standard date! this is the formula i'm using - =IF(I2=0,"",(S2+((D2+800)/I2)))

Is there a way to get around this? Appreciate your help! :beerchug:

Ian
 
Upvote 0
Ok Ian,

What is the resulting value from your IF formula, if the value is a valid date then the formula should still work.

Can you paste what the output of =IF(I2=0,"",(S2+((D2+800)/I2))) is?
 
Upvote 0
Morning RasGhul,

Column "O" is formatted as a "Date - 14/03/2012"

Cell I2 = "574" "General"
Cell S2 = "=Today()"
Cell D2 = Random number been "-1000:16000"

Thanks!
 
Upvote 0
Hi Ian,

The actual number that excel see's behind =IF(I2=0,"",(S2+((D2+800)/I2))) is e.g 43448.8741258741 which is not the same as 14-12-18 if we had that in the Dates header column.

We can get rid of all the decimal places with =IF(I2=0,"",ROUNDDOWN(S2+((D2+800)/I2),0)) which becomes e.g 43448 excel date serial number for 14-12-18.

**Note that your dates header (U1-AB etc) needs to be wide enough to match the random dates in the O Column.
 
Upvote 0
Hi RasGhul,

That works perfectly mate, thank you son much for your help! ?
 
Upvote 0
Hi RasGhul,

Sheets working great, but i’d Like to make a modification if it’s possible? Is there anyway I could insert a column somewhere that when it is a weekend I can enter “0” against that serial number so info it falls on a weekend date it carries it over to the next week day?
? thanks
 
Upvote 0
Hi Ian,

It may be easier to have your Dates header as workday dates only?
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,180
Members
453,021
Latest member
Justyna P

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