Split out multiple dates in a cell created by: Alt+ Enter

TheHack22

Board Regular
Joined
Feb 3, 2021
Messages
121
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
Hi All,

I don't know to write VBA, but I have adopted and edited syntax in the past. But I can't figure out how to do this.

I inherited a file at work with few thousands of lines. The ID# is in column A - Col B has multiple lines of data (Dates) in a single cell(Created Alt+Enter) for that same location. I would like split out the dates - add a new lines for each date in column B, while retain the ID Loc # for these dates in column A. Can someone please help me with this, if it's Possible to achieve in VBA? Please see sample file for your reference.

Thank you
Imran
1619031630035.png
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
You can certainly do it in VBA but you could also do it in Power Query if you are interested going down that road.

If you call your table tbl_Location
create a blank query and in the advanced query editor drop in this M Code.
It should work.

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="tbl_Location"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Location", type text}, {"Active/Future Pay Enhancement", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Active/Future Pay Enhancement", Splitter.SplitTextByDelimiter("#(lf)", QuoteStyle.Csv), {"Active/Future Pay Enhancement.1", "Active/Future Pay Enhancement.2", "Active/Future Pay Enhancement.3"}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Split Column by Delimiter", {"Location"}, "Attribute", "Value"),
    #"Removed Columns1" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"})
in
    #"Removed Columns1"
 
Last edited:
Upvote 0
Solution
It is hard to work with pictures. It would be easier to help if you could use the XL2BB add-in (icon in the menu) to attach a screenshot (not a picture) of your sheet. Alternately, you could upload a copy of your file to a free site such as www.box.com or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here.
 
Upvote 0
You can certainly do it in VBA but you could also do it in Power Query if you are interested going down that road.

If you call your table tbl_Location
create a blank query and in the advanced query editor drop in this M Code.
It should work.

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="tbl_Location"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Location", type text}, {"Active/Future Pay Enhancement", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Active/Future Pay Enhancement", Splitter.SplitTextByDelimiter("#(lf)", QuoteStyle.Csv), {"Active/Future Pay Enhancement.1", "Active/Future Pay Enhancement.2", "Active/Future Pay Enhancement.3"}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Split Column by Delimiter", {"Location"}, "Attribute", "Value"),
    #"Removed Columns1" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"})
in
    #"Removed Columns1"
Hi Alex,
Thanks very much for taking the time to help with this. This works perfectly. You're the best.
Imran
 
Upvote 0
It is hard to work with pictures. It would be easier to help if you could use the XL2BB add-in (icon in the menu) to attach a screenshot (not a picture) of your sheet. Alternately, you could upload a copy of your file to a free site such as www.box.com or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here.
Hi Mumps.,

Thank you very much for your message. I totally agree with you, pics don't help. Here is the dropbox link to my Ms Excel file. Alex helped me solved it by Power Query, if there is a way to do this by VBA that would help me a great deal as well.


Best,
Imran
 
Upvote 0
You can certainly do it in VBA but you could also do it in Power Query if you are interested going down that road.

If you call your table tbl_Location
create a blank query and in the advanced query editor drop in this M Code.
It should work.

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="tbl_Location"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Location", type text}, {"Active/Future Pay Enhancement", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Active/Future Pay Enhancement", Splitter.SplitTextByDelimiter("#(lf)", QuoteStyle.Csv), {"Active/Future Pay Enhancement.1", "Active/Future Pay Enhancement.2", "Active/Future Pay Enhancement.3"}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Split Column by Delimiter", {"Location"}, "Attribute", "Value"),
    #"Removed Columns1" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"})
in
    #"Removed Columns1"
Thanks a lot Alex,

This works perfectly. Your M Code was 100% correct. Your instructions were very clear as well, so I was able to complete this without any issues.
Imran
 
Upvote 0
@Imran_IsshackNY: Glad to hear you got the solution.
Please mark the solution post next time. I switched it in this thread by marking post #2 as the solution as you also confirmed.
 
Upvote 0
@Imran_IsshackNY: Glad to hear you got the solution.
Please mark the solution post next time. I switched it in this thread by marking post #2 as the solution as you also confirmed.
Hi Smozur,

Thanks for your note. I'm new to this forum and all this VBA and Power Query Stuff. Still trying to find my way around in this site. Do I click the check mark to mark as complete ?
Imran

1619136343289.png
 
Upvote 0
Hi Smozur,

Thanks for your note. I'm new to this forum and all this VBA and Power Query Stuff. Still trying to find my way around in this site. Do I click the check mark to mark as complete ?
Imran
No problem, Imran. My note was completely informative.

Yes, that's correct. If you received a working solution that solved your question, then just click on the checkmark icon next to the "solution post". So, future readers can see the solution faster.

Thanks, and Welcome to the MrExcel Board!
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,178
Members
453,021
Latest member
Justyna P

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