Help to reduce lengthy formula

malik641

Board Regular
Joined
Sep 6, 2005
Messages
65
I need to place this formula into 120,000 cells. Problem is, the workbook becomes quite LARGE (around 25MB extra from THESE cells alone) if I copy and paste the following formula into 10,000 rows by 12 columns.

Here's the formula with an explanaition following:

=IF(OR(Forecast!G2="",Actual!G2=""),"",IF(ISERROR(OR(DATEDIF(Forecast!G2,Actual!G2,"Y"),DATEDIF(Forecast!G2,Actual!G2,"ym"),DATEDIF(Forecast!G2,Actual!G2,"md"))),"",IF(AND(DATEDIF(Forecast!G2,Actual!G2,"Y")=0,DATEDIF(Forecast!G2,Actual!G2,"ym")=0,DATEDIF(Forecast!G2,Actual!G2,"md")=0),"Projected: "&TEXT(Forecast!G2,"dd-mmm-yyyy")&CHAR(10)&"On Time","Projected: "&TEXT(Forecast!G2,"dd-mmm-yyyy")&CHAR(10)&DATEDIF(Forecast!G2,Actual!G2,"Y")&" Years "&DATEDIF(Forecast!G2,Actual!G2,"ym")&" Months "&IF(DATEDIF(Forecast!G2,Actual!G2,"md")<=0,"0 Days",DATEDIF(Forecast!G2,Actual!G2,"md")&" Days"))))

This formula calls on two sheets: Forecast and Actual

Forecast and Actual contain dates on when the user thinks something will happen (hence, forecast) and when that something ACTUALLY does happen (and of course, Actual).

If the date on Actual exceeds the date on Forecast, it is considered late. Here is some sample data and results for late and on time dates.

Late
Forecast:
G2= 5/25/2005

Actual:
G2= 5/26/2005

Result from formula:

Projected: 5/25/2005
0 Years 0 Months 1 Days


On Time
Forecast:
G2= 5/25/2005

Actual:
G2= 5/20/2005

Result from formula:

Projected: 5/25/2005
On Time



And if either date is missing, it returns a blank.
Maybe I should reconsider the style of the results?

Thanks in advance[/b]
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
A little better...

Code:
=IF(OR(Forecast!G2="",Actual!G2=""),"","Projected: "&TEXT(Forecast!G2,"dd-mmm-yyyy")&CHAR(10)&IF(Forecast!G2<Actual!G2,DATEDIF(Forecast!G2,Actual!G2,"y")&" years "&DATEDIF(Forecast!G2,Actual!G2,"ym")&" months "&DATEDIF(Forecast!G2,Actual!G2,"md")&" days","On Time"))
 
Upvote 0
Thanks Oaktree :biggrin: Just what I needed.

And I just spoke to my boss and she said I won't need to use 10,000 rows....only about 500. So even better now :LOL:
 
Upvote 0

Forum statistics

Threads
1,214,397
Messages
6,119,273
Members
448,883
Latest member
fyfe54

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