Last Date in Month

moppenhe

New Member
Joined
May 28, 2009
Messages
29
I have a list of historical stock prices and their corresponding dates and I am trying to calculate quarterly returns. To calculate this I am trying to use a vlookup where the lookup value is = Vlookup(year,month +1,0),.... to return the last day of the month that starts and ends the quarter.

The problem is that there is no data in there for weekends so if the last day of a trading month is 8/29/09, then it returns an #N/A

Anyone have any ideas on how to overcome this? It would be nice if I could have it look up the max day in that given month, but I dont know if this is possible.

Thanks,

MBO
 

Some videos you may like

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.

c_m_s_jr

Well-known Member
Joined
Mar 23, 2009
Messages
1,561
If you are using 2003 you need to install the Analysis Tool Pack to use this, but maybe:

=VLOOKUP(EOMONTH(A1,0),$D$1:$E$2,2,FALSE)

Where EOMONTH will calculate the last day of the month for the given date in A1. So if A1 = 1/15/2009 it would calculate 1/31/2009
 

moppenhe

New Member
Joined
May 28, 2009
Messages
29
The problem is that if the data does not have 1/31/2009 in there but cuts of on Friday the 29th of 2009. (I am not actually sure if the 29th of January was a friday but this is just an example to help describe me issue).
 

c_m_s_jr

Well-known Member
Joined
Mar 23, 2009
Messages
1,561
If you can post more information I think that will help. I thought you wanted it to look up the last day of the month.

Your VLOOKUP is not clear on how your data is structured or what you are going after.
 

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
If your dates are listed in ascending order then just change your VLOOKUP to use TRUE as 4th argument.....then if the last day of the month doesn't exist in the data it'll find the previous one, i.e. the last date listed for that month.

or if not sorted ascending you can use an array formula to get the latest date in that month

=MAX(IF(Dates< DATE(year,month+1,1),Dates))

confirmed with CTRL+SHIFT+ENTER<DATE(YEAR,MONTH+1,1),DATES))< p>
 

drsarao

Well-known Member
Joined
Sep 9, 2009
Messages
1,143
Office Version
  1. 2007
Platform
  1. Windows
I think Barry's first solution is spot-on.

Another way would be to see if last date is a Sun/Sat and return last Fri in that case. Vog has given a formula for it I think.

A different formula for the same:

=IF(WEEKDAY(A1,3) > 4,A1+4-WEEKDAY(A1,3),A1)
 

Watch MrExcel Video

Forum statistics

Threads
1,122,841
Messages
5,598,390
Members
414,234
Latest member
grlevesq

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
Top