How to join text as a date

kofi11

New Member
Joined
Jun 19, 2024
Messages
5
Office Version
  1. 365
Platform
  1. Windows
Hi,

I have a large dataset where each case reference may have multiple lines. For example showing which staff member made a visit.

I have been asked to join these staff members in a single cell so I use the following formula:

=IF(A2=A1," ",TEXTJOIN(", ",TRUE,OFFSET(P2,0,0,COUNTIF(A:A,A2,1)))

Column A holds all case references. Column P holds the visit staff.

This works fine. But when asked to do the same and join all the visit dates, I just get the 5 digits numbers instead of a string of dd/mm/yyyy dates separed by commas.

The number format is already set to date but the dates still appear as 5 digit numbers.

Can anybody suggest a solution please?
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Simplified version of what I'm after shown below on the attached....
 

Attachments

  • 1000029258.jpg
    1000029258.jpg
    222.2 KB · Views: 5
Upvote 0
just use text() infront of whatever you used to join the date
the date is a number , hence why you get that
Text(formula returns the date , "DD/MM/YYYY")
that will change the date to the format you want

whats the visit date formula you have working

TEXT( textjoin(........), "DD/MM/YYYY")
 
Upvote 0
=IF(A2=A1," ",TEXTJOIN(", ",TRUE,OFFSET(P2,0,0,COUNTIF(A:A,A2,1)))

is the formula I have working to join the data.

Works fine except where I want to join dates.
 
Upvote 0
that shjould give an error -
COUNTIF(A:A,A2,1)
not a correct formula

Note: Images are difficult to see , and also requires that I input all the data myself, which means I may make an error, which is very time consuming, and from my point of view less likely to get a response, if a complicated spreadsheet. Plus we cannot see any of the formulas used.

Therefore -

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.

This will possibly enable a quicker and more accurate solution for you.

MrExcel has a tool called “XL2BB” that lets you post samples of your data and will allow us to copy/paste your sample data into our Excel spreadsheets, saving a lot of time.

You can also test to see if it works ok, in the "Test Here" forum.

OR if you cannot get XL2BB to work, or have restrictions on your PC

then put the sample spreadsheet onto a share

I only tend to goto OneDrive, Dropbox or google docs , as I'm never certain of other random share sites and possible virus.
Please make sure you have a representative data sample and also that the data has been desensitised, remember this site is open to anyone with internet access to see - so any sensitive / personal data should be removed

Make sure you set any share or google to share to everyone
 
Upvote 0
How about
Excel Formula:
=IF(A2=A1,"",TEXTJOIN(", ",,TEXT(FILTER($B$2:$B$100,($A$2:$A$100=A2)*($B$2:$B$100<>"")),"dd/mm/yyyy")))
 
Upvote 0
Could use ARRAYTOTEXT:
Excel Formula:
=IF(A2=A1,"",ARRAYTOTEXT(TEXT(FILTER($B$2:$B$18,($A$2:$A$18=A2)*($B$2:$B$18<>""),""),"dd/mm/yyyy")))
Book1
ABC
1CaseVisit DateJoined Visit Date
24 
35 
47 
58 
69 
710 
811 
91219/06/2024
101219/06/2024 
1114 
1217 
131819/06/2024, 20/06/2024, 21/06/2024
1418 
151819/06/2024 
161820/06/2024 
171821/06/2024 
1820 
Sheet1
Cell Formulas
RangeFormula
C2:C18C2=IF(A2=A1,"",ARRAYTOTEXT(TEXT(FILTER($B$2:$B$18,($A$2:$A$18=A2)*($B$2:$B$18<>""),""),"dd/mm/yyyy")))
 
Upvote 1
Thanks, this works great but I have the added issue of only wanting to add those with the same ref together. See attached
Could use ARRAYTOTEXT:
Excel Formula:
=IF(A2=A1,"",ARRAYTOTEXT(TEXT(FILTER($B$2:$B$18,($A$2:$A$18=A2)*($B$2:$B$18<>""),""),"dd/mm/yyyy")))
Book1
ABC
1CaseVisit DateJoined Visit Date
24 
35 
47 
58 
69 
710 
811 
91219/06/2024
101219/06/2024 
1114 
1217 
131819/06/2024, 20/06/2024, 21/06/2024
1418 
151819/06/2024 
161820/06/2024 
171821/06/2024 
1820 
Sheet1
Cell Formulas
RangeFormula
C2:C18C2=IF(A2=A1,"",ARRAYTOTEXT(TEXT(FILTER($B$2:$B$18,($A$2:$A$18=A2)*($B$2:$B$18<>""),""),"dd/mm/yyyy")))
Thank you so much, this is the closest to what I need. Just on your example, for case 18, I would need to show those first visits as blanks (1900).
I've been trying to incorporate that but no luck so far. Any ideas?
 

Attachments

  • 1000029258.jpg
    1000029258.jpg
    222.2 KB · Views: 3
Upvote 0
In that case try
Excel Formula:
=IF(A2=A1,"",TEXTJOIN(", ",,TEXT(FILTER($B$2:$B$100,$A$2:$A$100=A2),"dd/mm/yyyy")))
 
Upvote 1
Solution

Forum statistics

Threads
1,218,212
Messages
6,141,167
Members
450,341
Latest member
switfyu2

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