Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Hi,
I have date column as text the format is DMMYYYY, I need to transform it to YYYY-MM-DD. Please help. Thanks
Solved! Go to Solution.
Hi @idramadhara ,
Assuming your original text date column is called [dateText], enter this as a new custom column:
Text.Combine(
{
Text.End([dateText], 4),
Text.Range([dateText], Text.Length([dateText]) - 6, 2),
Text.PadStart(Text.Start([dateText], Text.Length([dateText]) - 6), 2, "0")
},
"-"
)
This outputs in a text format, but will also be recognised perfectly by PQ if you want to convert to native date type.
Example output:
Full example query:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwMDICIqVYHRAHwQaz4BwktqWhIZBtDNFgamAOkYgFAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [dateText = _t]),
addDate = Table.AddColumn(Source, "date", each
Text.Combine(
{
Text.End([dateText], 4),
Text.Range([dateText], Text.Length([dateText]) - 6, 2),
Text.PadStart(Text.Start([dateText], Text.Length([dateText]) - 6), 2, "0")
},
"-"
)
)
in
addDate
Pete
Proud to be a Datanaut!
Hi @idramadhara ,
Assuming your original text date column is called [dateText], enter this as a new custom column:
Text.Combine(
{
Text.End([dateText], 4),
Text.Range([dateText], Text.Length([dateText]) - 6, 2),
Text.PadStart(Text.Start([dateText], Text.Length([dateText]) - 6), 2, "0")
},
"-"
)
This outputs in a text format, but will also be recognised perfectly by PQ if you want to convert to native date type.
Example output:
Full example query:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwMDICIqVYHRAHwQaz4BwktqWhIZBtDNFgamAOkYgFAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [dateText = _t]),
addDate = Table.AddColumn(Source, "date", each
Text.Combine(
{
Text.End([dateText], 4),
Text.Range([dateText], Text.Length([dateText]) - 6, 2),
Text.PadStart(Text.Start([dateText], Text.Length([dateText]) - 6), 2, "0")
},
"-"
)
)
in
addDate
Pete
Proud to be a Datanaut!
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
25 | |
12 | |
12 | |
11 | |
8 |
User | Count |
---|---|
42 | |
27 | |
14 | |
13 | |
13 |