Transforming Text to Date in Power Query

scpournara

New Member
Joined
Aug 24, 2014
Messages
40
I ma trying to transfomr an 8 digit text to a Date in Power Query. For instance, I want to transform in Power Query 02012021 to 02/01/2021 and format it
as a date? Thanks.
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", Int64.Type}}),
    #"Split Column by Position" = Table.SplitColumn(Table.TransformColumnTypes(#"Changed Type", {{"Date", type text}}, "en-US"), "Date", Splitter.SplitTextByPositions({0, 4}, true), {"Date.1", "Date.2"}),
    #"Split Column by Position1" = Table.SplitColumn(Table.TransformColumnTypes(#"Split Column by Position", {{"Date.1", type text}}, "en-US"), "Date.1", Splitter.SplitTextByPositions({0, 2}, true), {"Date.1.1", "Date.1.2"}),
    #"Merged Columns" = Table.CombineColumns(#"Split Column by Position1",{"Date.1.1", "Date.1.2", "Date.2"},Combiner.CombineTextByDelimiter("/", QuoteStyle.None),"New Date"),
    #"Changed Type1" = Table.TransformColumnTypes(#"Merged Columns",{{"New Date", type date}})
in
    #"Changed Type1"

This example placed the date (text) was in Column A
 
Upvote 0
My approach would be adding a custom column with the following line of code.

#date(Number.FromText(Text.End([Day],4)),Number.FromText(Text.Start([Day],2)),Number.FromText(Text.Middle([Day],2,2)))

Add column > custom column> then "[Day]" which should be replaced by your column name pointing to the date in text format.

 
Upvote 0
Solution
My approach would be adding a custom column with the following line of code.

#date(Number.FromText(Text.End([Day],4)),Number.FromText(Text.Start([Day],2)),Number.FromText(Text.Middle([Day],2,2)))

Add column > custom column> then "[Day]" which should be replaced by your column name pointing to the date in text format.

Wow, worked great!!!. Thanks. I am new to PowerQuery and have made great progress but get stuck every once in a while.

I do have another question after trying to solve it, but have been unsuccessful. I am importing a column that is formatted as General in the Orginal file. The data in each column contains records that are all different make-ups: 8 digits (45432689), multiple digits with characters(45R4367), and digits with characters and symbols (R-789876). When I "Close and Load" to the data file, I get an error. I am OK with formatting as Text, but still, get errors. Any ideas?
 
Upvote 0
(The custom column might be returning errors. Make sure that the result is returning no errors.)
Formula above is on an assumption that your text is formatted in MMDDYYYY so it is splitting it into #date(YYYY,MM,DD) you might need to switch the formulas.

*Also maybe you need to set the custom column to your local date.

Click the left most part of your custom column and click "Using Locale..."
Then set it in a way in such that your column date is similar to the custom column.

just a guess tho.
 

Attachments

  • etc.PNG
    etc.PNG
    9 KB · Views: 55
Upvote 0

Forum statistics

Threads
1,214,535
Messages
6,120,090
Members
448,944
Latest member
sharmarick

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