Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
dsabsi
Advocate I
Advocate I

How to convert text (data type) to a date (data type)?

Hello guys, 

 

I need your help with converting a text column towards a data type. 

Should i add a column with a certain formula to achieve this? 

 

See below the error that I'm getting from this: 

Verzoek Chris.JPG

Many thanks!!!

 

Cheers,

 

DSabsi 

 

 

 

1 ACCEPTED SOLUTION

Sure (I included some Dutch as well 🙂 😞

 

let
    Source = #table(type table[Verwachte_Start = text],{{"1499032800"},{"1498860000"},{"1493589600"},{"1491170400"}}),
    AddedUTCDateTime = Table.AddColumn(Source, "Verwachte_startdatum/tijd_UTC", each #datetimezone(1970,1,1,0,0,0,0,0) + #duration(0,0,0,Number.From([Verwachte_Start])), type datetimezone),
    AddedLocalDate = Table.AddColumn(AddedUTCDateTime, "Verwachte_startdatum_lokaal", each Date.From([#"Verwachte_startdatum/tijd_UTC"]), type date)
in
    AddedLocalDate
Specializing in Power Query Formula Language (M)

View solution in original post

14 REPLIES 14
Nari1998
Helper II
Helper II

Hi All,

I'm stuck at creating a custom date column.
So the thing is i have a date column which is in text datatype as following 09-01-24 (which should be date as in 9 January 2024) and when converting into date it gives error on some dates.

How can i fix this in pq?

v-shex-msft
Community Support
Community Support

Hi @dsabsi,

 

It will be help if you share some sample data or date structure.

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Hi Guys @v-shex-msft@SivaMani@MarcelBeug@blopez11

 

I found out that the text value is an epoch value in a text value. 

Do you know how to convert an epoch value in a text format to dates value in date format? 

 

Cheers, 

 

DSabsi

Sure (I included some Dutch as well 🙂 😞

 

let
    Source = #table(type table[Verwachte_Start = text],{{"1499032800"},{"1498860000"},{"1493589600"},{"1491170400"}}),
    AddedUTCDateTime = Table.AddColumn(Source, "Verwachte_startdatum/tijd_UTC", each #datetimezone(1970,1,1,0,0,0,0,0) + #duration(0,0,0,Number.From([Verwachte_Start])), type datetimezone),
    AddedLocalDate = Table.AddColumn(AddedUTCDateTime, "Verwachte_startdatum_lokaal", each Date.From([#"Verwachte_startdatum/tijd_UTC"]), type date)
in
    AddedLocalDate
Specializing in Power Query Formula Language (M)

Hi @MarcelBeug

 

Thank you for your solution, you're great!

I also learned that an alternative to this is: 

1. Convert the text to a number by the following formula (creat new column) : Verwachte start number = value([verwachte_start] )/(60*60*24) 

2. Convert the value to a year date format (create new column) : Verwachte StartJaar = YEAR(IF([Verwachte start number] = BLANK() ;BLANK();DATEVALUE("01/01/1970") + [Verwachte start number])) 

 

Cheers, 

 

DSabsi

Hi @MarcelBeug

 

Thank you for your answer (and of course in Dutch 😉 I appreciate that. 

 

Should I try your formula in a column or through edit-queries? 

 

Cheers, 

 

DSabsi

My solutions are always (99.9%) via Edit Queries.

Specializing in Power Query Formula Language (M)
SivaMani
Resident Rockstar
Resident Rockstar

HI @dsabsi

Go to query editor and create custom column with the following formula,

 

Date.FromText([DateField],Corresponding culture code)

 

Regards,

Siva

@SivaMani How do you know that the culture code should be "en-GB", without any information from @dsabsi how his dates look like?

 

Just to give an impression: below some date formats for April 1, 2017, and the number of culture codes using that format:

Some date formats.png

Specializing in Power Query Formula Language (M)

@MarcelBeug In my experience, Power BI's default date format is MM/DD/YYYY - Because of Locale(by default) in English(United State).  

 

GB's date format is DD/MM/YYYY.

 

According to your sample date formats,

4th (2017-04-01) and 6th(4/1/2017) formats will be detected as a date by Power BI.

The Rest of them, we have to convert it to the required format. Since it is in English(GB) format. So I have used "en-GB"

 

I hope I've made it clear enough. 

 

If you have anything apart from this, just tell me it will be helpful.

 

Thanks,

Siva

 

The default depends on your Regional Settings in Windows when you create a new Power BI Desktop file.

 

Again: we didn't get any information how the dates look like, so we just don't know and can only guess.

 

Just to give you an idea: there are almost 600 different culture codes, that may influence formats (dates, numbers, of course names of days and months) and even the A-Z sort order, e.g. Hawaii puts the vowels up front:

 

A-Z by culture code.png

 

Otherwise of course not all cultures use the characters A-Z as their alphabet.

 

Specializing in Power Query Formula Language (M)

@MarcelBeug Thank you so much for your valuable information. 

blopez11
Resident Rockstar
Resident Rockstar

Can you give us a sample of what your text data looks like and what data type you are trying to convert it to?  That would help in providing an answer

Hello guys, 

 

My apologies for my late response. 

Hereby the sample of the data that I got from my boss:verwachte start.JPG

 

 

The format is text and I wish to change it to dates. 

 

I hope you can help me, I'm really astonished by the amount of replies (many thanks!!!!)

 

Cheers, 

 

DSabsi

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.