cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

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
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

Check out the November 2023 Power BI update to learn about new features.

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.

Top Solution Authors