Formula with array constant

searchsolution

New Member
Joined
Jan 18, 2014
Messages
5
I am having trouble to get a solution for creating a formula to calculate with an array constant and then tell me if the calculated amounts equal a designated amount. This is what I have so far:

=IF(SUM(YEAR(A2)+{5;10;15;20;25;30;35;40;45;50})=YEAR(TODAY());"jubilee";"")

Can anyone help quickly?
 

Some videos you may like

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,718
Office Version
  1. 2010
Platform
  1. Windows
I am having trouble to get a solution for creating a formula to calculate with an array constant and then tell me if the calculated amounts equal a designated amount. This is what I have so far:

=IF(SUM(YEAR(A2)+{5;10;15;20;25;30;35;40;45;50})=YEAR(TODAY());"jubilee";"")

Can anyone help quickly?

You will need to explain in words what you think that formula should be doing. One of my main questions is are the number in the array years or days?
 

searchsolution

New Member
Joined
Jan 18, 2014
Messages
5
the formula should be checking if the value for the current year can be found within the calculated values of the array. The numbers within the array are multiples of 5 indicating the jubilee increments.

Ex: entry date 01.01.2004 / jubilee date: 2009, 2014, 2019, ...
 

searchsolution

New Member
Joined
Jan 18, 2014
Messages
5
I have found the solution!

=IF(OR(YEAR(TODAY())=(YEAR(A2)+{5;10;15;20;25;30;35;40;45;50}));"jubilee";"")

thx anyhow Rick!
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,718
Office Version
  1. 2010
Platform
  1. Windows

ADVERTISEMENT

I have found the solution!

=IF(OR(YEAR(TODAY())=(YEAR(A2)+{5;10;15;20;25;30;35;40;45;50}));"jubilee";"")

thx anyhow Rick!
You did not find "the solution", you found "a solution". Just in case you are interested, here is a shorter formula that will work (without the need for an array) for any year from 1900 up to 9999...

=IF(MOD(YEAR(TODAY())-YEAR(A2),5),"","Jubillee")
 

searchsolution

New Member
Joined
Jan 18, 2014
Messages
5
Hi Rick, yes, it was one of maybe many solutions. Naturally the best solution is the most concise and simple. I tried out your solution as well and it worked. The only challenge would be if the service entry date is the actual year, then your solution would also indicate "jubilee" even though the employee had only started in the current year. I will definitely check out how I can use your solution to make it only work for every five years. Thx again and I certainly appreciate the support!
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,718
Office Version
  1. 2010
Platform
  1. Windows
Hi Rick, yes, it was one of maybe many solutions. Naturally the best solution is the most concise and simple. I tried out your solution as well and it worked. The only challenge would be if the service entry date is the actual year, then your solution would also indicate "jubilee" even though the employee had only started in the current year. I will definitely check out how I can use your solution to make it only work for every five years. Thx again and I certainly appreciate the support!

Ah, you only want to examine years prior to today. Then I guess this modification would work (but now my formula is getting longer, although it avoids the array and covers more years than that array did)...

=IF(OR(YEAR(A2)>=YEAR(TODAY()),MOD(YEAR(TODAY())-YEAR(A2),5)),"","Jubillee")
 
Last edited:

searchsolution

New Member
Joined
Jan 18, 2014
Messages
5
exactly what i worked out as well! I must be on the best path though I never thought of using "mod" as a possibility, because I have never been exposed to it before. I need more challenges and better understanding of the various functions. Search ended
 

Watch MrExcel Video

Forum statistics

Threads
1,123,402
Messages
5,601,475
Members
414,452
Latest member
Dannysamworth

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