Year from date

jarhead58

Active Member
Joined
Sep 21, 2017
Messages
364
Office Version
  1. 2021
Platform
  1. Windows
Hey everyone!! Hope you all had a great holiday season!!

I have J4 set with "=Mode(B4:B105)" which column B contain various numbers. Column A cells are dates, (A4=1/1/2019, A5=12/28/2018....etc going backward) How can I change the value of J4 ":B105" to the column B cell number closest to a year from the date of A4 or is it not possible? TIA
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Say A4 has 1/2/19, I'm looking for the closest same date except for it being a year ago like 1/2 or 1/4/2018 within 2 days of A4 date! Does that help?

Go the formula:

CellFormula
D4=MODE(INDIRECT("B4:B"&MATCH(DATE(YEAR(A4)-1,MONTH(A4),DAY(A4)),A1:A400,-1)))

<tbody>
</tbody>
 
Upvote 0
DanteAmor, thanks for the help my friend but we got it working now!!
 
Upvote 0
Amended to look at minus 1 year

=MODE(OFFSET(B4,,,MATCH(EDATE(A4,-12),A5:A10000,-1)))

Hey gaz_chops, what if I wanted to include other columns, say B4:F105 rather than(B4,,,MATCH......, asking for a friend lol?
 
Last edited:
Upvote 0
Hi,

Try repeating the the Offset formula, changing the "B" to be the NEW column to include.

=MODE(OFFSET(B4,,,MATCH(EDATE(A4,-12),A4:A10000,-1)),OFFSET(C4,,,MATCH(EDATE(A4,-12),A4:A10000,-1)),OFFSET(D4,,,MATCH(EDATE(A4,-12),A4:A10000,-1)),OFFSET(E4,,,MATCH(EDATE(A4,-12),A4:A10000,-1)),OFFSET(F4,,,MATCH(EDATE(A4,-12),A4:A10000,-1)))

Gaz
 
Upvote 0

Forum statistics

Threads
1,215,049
Messages
6,122,864
Members
449,097
Latest member
dbomb1414

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