year of the date

mark692

Active Member
Joined
Feb 27, 2015
Messages
321
Office Version
  1. 2016
Platform
  1. Windows
i want to put a formula on column C that will show me the year of the given date on column A inside the same group code in column B, like this


Excel 2013/2016
ABC
1DateGroup CodeYear
203/17/201812018
312018
412018
503/06/201722016, 2017
601/01/201622016, 2017
722016, 2017
812/01/201732017
932017
Sheet1
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Does each code group always occupy exactly 3 rows as shown in your example?
 
Upvote 0
See if this UDF (user defined function) does what you want...
Code:
Function GroupDates(GroupNum As Long) As String
  Dim R As Long, Dates As Variant
  Dates = Range(Cells(1, "B"), Cells(Rows.Count, "B").End(xlUp))
  For R = UBound(Dates) To 1 Step -1
    If Cells(R, "B").Value = GroupNum And Cells(R, "A") <> "" Then
      GroupDates = GroupDates & ", " & Year(Cells(R, "A").Value)
    End If
  Next
  GroupDates = Mid(GroupDates, 3)
End Function

HOW TO INSTALL UDFs
------------------------------------
If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use GroupDates just like it was a built-in Excel function. For example,

=GroupDates(B2)

If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0
If you have Excel 2016, you can use this or UDF is the way to go for you as given by Rick Rothstein :


Unknown
ABC
1DateGroup CodeYear
203/17/201812018
312018
412018
503/06/201722017,2016
601/01/201622017,2016
722017,2016
812/01/201732017
932017
10
Sheet13
Cell Formulas
RangeFormula
C2{=TEXTJOIN(",",,IF(($B$2:$B$9=B2)*($A$2:$A$9<>""),YEAR($A$2:$A$9),""))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Last edited:
Upvote 0
If you have Excel 2016, you can use this or UDF is the way to go for you as given by Rick Rothstein :

Unknown
ABC
1DateGroup CodeYear
203/17/201812018
312018
412018
503/06/201722017,2016
601/01/201622017,2016
722017,2016
812/01/201732017
932017
10

<tbody>
</tbody>
Sheet13

Array Formulas
CellFormula
C2{=TEXTJOIN(",",,IF(($B$2:$B$9=B2)*($A$2:$A$9<>""),YEAR($A$2:$A$9),""))}

<tbody>
</tbody>
Enter the formula with "Ctrl+Shift+Enter". Only Pressing "Enter" will result in formula giving error or incorrect result. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>

Hi im using my your formula bat it gives me result like this yes im using 2016 thanks

ABC
1dategroupyear
201/21/20181#NAME?
301/21/20171#NAME?
41#NAME?
502/21/20172#NAME?
602/21/20172#NAME?

<colgroup><col style="width: 25pxpx"><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Array Formulas
CellFormula
C2{=TEXTJOIN(",",,IF(($B$2:$B$6=B2)*($A$2:$A$6<>""),YEAR($A$2:$A$6),""))}
C3{=TEXTJOIN(",",,IF(($B$2:$B$6=B3)*($A$2:$A$6<>""),YEAR($A$2:$A$6),""))}
C4{=TEXTJOIN(",",,IF(($B$2:$B$6=B4)*($A$2:$A$6<>""),YEAR($A$2:$A$6),""))}
C5{=TEXTJOIN(",",,IF(($B$2:$B$6=B5)*($A$2:$A$6<>""),YEAR($A$2:$A$6),""))}
C6{=TEXTJOIN(",",,IF(($B$2:$B$6=B6)*($A$2:$A$6<>""),YEAR($A$2:$A$6),""))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Last edited:
Upvote 0
See if this UDF (user defined function) does what you want...
Code:
Function GroupDates(GroupNum As Long) As String
  Dim R As Long, Dates As Variant
  Dates = Range(Cells(1, "B"), Cells(Rows.Count, "B").End(xlUp))
  For R = UBound(Dates) To 1 Step -1
    If Cells(R, "B").Value = GroupNum And Cells(R, "A") <> "" Then
      GroupDates = GroupDates & ", " & Year(Cells(R, "A").Value)
    End If
  Next
  GroupDates = Mid(GroupDates, 3)
End Function

HOW TO INSTALL UDFs
------------------------------------
If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use GroupDates just like it was a built-in Excel function. For example,

=GroupDates(B2)

If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.


hello sir your formula works but when i tried to apply it on may real working workbook it gives me error
 
Upvote 0
like this sir,

year_image.jpg
[/URL][/IMG]


its gives me 2016,2016,2015,2015,2015

instead of 2016,2015 only

the group code is the column that colored yellow
 
Upvote 0
maybe you need to add: Application.Volatile before last Line for update Auto or Use F9

GroupDates = Mid(GroupDates, 3)
Application.Volatile
End Function
 
Upvote 0

Forum statistics

Threads
1,214,395
Messages
6,119,265
Members
448,881
Latest member
Faxgirl

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