extract year value and rearrange

freeriding

New Member
Joined
Sep 21, 2015
Messages
22
Hallo! i have a column with dates (eg 1/1/2019) and want to extract the years, and put them in a row from oldest to newest.

eg. i have in a column these dates:
  • 1/1/2017
  • 1/3/2017
  • 1/1/2018
  • 2/1/2018
  • 1/1/2019
  • 5/1/2019

and want to extract the years in 3 consecutive cells in a row from oldest to newest: 2017 | 2018 | 2019
 
Last edited:

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"
Hi,

Assuming those values are in A1:A6, array formula**:

=IFERROR(SMALL(IF(FREQUENCY(YEAR($A1:$A6),YEAR($A1:$A6)),YEAR($A1:$A6)),COLUMNS($A1:A1)),"")

and copied to the right until you start to get blanks for the results.

Regards


**Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
 
Upvote 0
awesome, thank you very much! The only problem, is when i have some blank rows between the dates, then i get a 1900 value in the array formula! Why is that and how do i fix this?

eg. i get in the above example: 1900 | 2017 | 2018 | 2019
 
Upvote 0
Ok, then use:

=IFERROR(SMALL(IF(FREQUENCY(IF($A1:$A6<>"",YEAR($A1:$A6)),YEAR($A1:$A6)),YEAR($A1:$A6)),COLUMNS($A1:A1)),"")

Regards
 
Upvote 0

Forum statistics

Threads
1,223,886
Messages
6,175,189
Members
452,616
Latest member
intern444

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