cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
idramadhara
Frequent Visitor

Transform Date from DMMYYYY to YYYY-MM-DD

Hi,

I have date column as text the format is DMMYYYY, I need to transform it to YYYY-MM-DD. Please help. Thanks

 

idramadhara_0-1669974357670.png

 

1 ACCEPTED SOLUTION
BA_Pete
Super User
Super User

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:

BA_Pete_0-1669978225402.png

 

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



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




View solution in original post

2 REPLIES 2
idramadhara
Frequent Visitor

Thanks @BA_Pete it works

BA_Pete
Super User
Super User

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:

BA_Pete_0-1669978225402.png

 

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



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




Helpful resources

Announcements
T-Shirt Design Challenge 2023

Power BI T-Shirt Design Challenge 2023

Submit your creative T-shirt design ideas starting March 7 through March 21, 2023.

March 2023 Update3

Power BI March 2023 Update

Find out more about the March 2023 update.

March Events 2023A

March 2023 Events

Find out more about the online and in person events happening in March!

Top Solution Authors
Top Kudoed Authors