Why won't date formula work?

pilot

Active Member
Joined
Feb 17, 2002
Messages
345
This formula in A1 properly displays 2004

=YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC(((DATE(Base,12,31))-$AI$2)/365),YEARS)),SICK)+1),SICK,0))

This formula in A2 properly displays 01-01-04

=DATE(A1,1,1)

When I replace A1 in the formula above with the actual formula from A1, I get an error with DATE just after ((( highlighted. Why won't this work?

=DATE((YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC(((DATE(Base,12,31))-$AI$2)/365),YEARS)),SICK)+1),SICK,0))),1,1)
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
On 2002-03-29 06:43, pilot wrote:
This formula in A1 properly displays 2004

=YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC(((DATE(Base,12,31))-$AI$2)/365),YEARS)),SICK)+1),SICK,0))

This formula in A2 properly displays 01-01-04

=DATE(A1,1,1)

When I replace A1 in the formula above with the actual formula from A1, I get an error with DATE just after ((( highlighted. Why won't this work?

=DATE((YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC(((DATE(Base,12,31))-$AI$2)/365),YEARS)),SICK)+1),SICK,0))),1,1)

Hi Pilot:
If your formula for the year in A1 works OK, then a cursory look at your formula in A2, shows you have an extra left parentheses ...
so replace the formual in A2 with

=DATE(YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC(((DATE(Base,12,31))-$AI$2)/365),YEARS)),SICK)+1),SICK,0))),1,1)

I have not cheked this formula ... but give it a shot.

Please post back if it works for you ... otherwise explain a little further and let us take it from there!




_________________
Yogi Anand

Edit: Deleted inactive website from hardcoded signature
This message was edited by Yogi Anand on 2003-01-19 14:19
 
Upvote 0
The formula in A2 works and I count the net parentheses as zero. In your suggestion, I count one extra right paren. It's gotta be something else. Thanks for all help.
 
Upvote 0
On 2002-03-29 07:07, pilot wrote:
The formula in A2 works and I count the net parentheses as zero. In your suggestion, I count one extra right paren. It's gotta be something else. Thanks for all help.

That's right, I mean, your hypothesis. I'd like to have a look at the WB itself, if possible.

Aladin
 
Upvote 0
On 2002-03-29 07:07, pilot wrote:
The formula in A2 works and I count the net parentheses as zero. In your suggestion, I count one extra right paren. It's gotta be something else. Thanks for all help.

Hi Pilot:
Some times it is so difficult to check -- especially one's own work. If you like you can email your workbook to me and I will be glad to look at where the problem might be.
 
Upvote 0
Hi Jim:
I did get you workbook -- I did analyze it. The problem was that in using the year calculation in the date formula you exceeded the limit of 7 levels of nested functions. It is surprising that Excel will not point this out but consider this an error. Solution -- use the results of your year calculation in another formula so you don't exceed the limit of nested functions.

Please post back if it works for you ... otherwise explain alittle further and let us take it from there!
 
Upvote 0

This formula in A1 properly displays 2004

=YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC(((DATE(Base,12,31))-$AI$2)/365),YEARS)),SICK)+1),SICK,0))

This formula in A2 properly displays 01-01-04

=DATE(A1,1,1)

When I replace A1 in the formula above with the actual formula from A1, I get an error with DATE just after ((( highlighted. Why won't this work?

=DATE((YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC(((DATE(Base,12,31))-$AI$2)/365),YEARS)),SICK)+1),SICK,0))),1,1)


Pilot,

I see you already got a reply as to the nature of the problem: Wrapping the first working formula within an additional function causes to exceed a built-in limit in Excel. One solution is what Yogi suggested, another for which I opted is:

=DATE(YEAR($AI$2)+INDEX(YEARS,MATCH(INDEX(SICK,MATCH(INDEX(SICK,MATCH(TRUNC((BaseDate-$AI$2)/365),YEARS)),SICK)+1),SICK,0)),1,1)

where BaseDate is a named formula consisting of:

[A]

=DATE(Base,12,31)

If this solution sounds good to you,

activate Insert|Name|Define,
enter BaseDate (or something more intelligible) as name in the Names in Workbook box, and
enter [A] as formula in the Refers to box.

Aladin
This message was edited by Aladin Akyurek on 2002-03-29 11:20
 
Upvote 0
Thanks Yogi and Aladin, it works like a charm. I like the limitation workaround that Aladin suggested - and I learned something new and quite useful, too. This is a great resource!!!
 
Upvote 0

Forum statistics

Threads
1,213,550
Messages
6,114,265
Members
448,558
Latest member
aivin

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