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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
rodriguise
Regular Visitor

RFC3339 Dates

Dates in my source are stored in RFC3339 "2006-01-02T15:04:05.000Z07:00". The DateValue function does not like this, how can I make use of date function in the platform?

1 ACCEPTED SOLUTION

In Power Query, such dates can be converted to datetimezone format using formula

 

DateTimeZone.From(Text.Replace([Input],"Z","+"))

and changing the data type to date/time/timezone.

 

 

The data model doesn't have datetimezone format: when the result from Power Query is loaded into the data model, the UTC Offset is just cut off. If the data type is left as "any" in Power Query, the result loads as text.

Power Query has several functions to switch the UTC Offset and to convert datetimezone data to local date/time.

In the picture below you can see the input and 3 columns with the result from the formula above (my culture code is set to "en-US"): as datetimezone, as any, as datetime (which converts the datetimezone to the local UTC Offset; in my case, on January 2, 2006 +01:00, so 6 hours behind UTC Offset +07:00 and 8 hours ahead of UTC Offset -07:00).

 

DTZ in PQ and Data Model.png

Specializing in Power Query Formula Language (M)

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

You could create a new column and make use of String manipulation formula's to extract out the portion you care about.

For example a LEFT(<Fieldname>, 10) would get the date portion.

(Right and MID should handle anything else you need)

In Power Query, such dates can be converted to datetimezone format using formula

 

DateTimeZone.From(Text.Replace([Input],"Z","+"))

and changing the data type to date/time/timezone.

 

 

The data model doesn't have datetimezone format: when the result from Power Query is loaded into the data model, the UTC Offset is just cut off. If the data type is left as "any" in Power Query, the result loads as text.

Power Query has several functions to switch the UTC Offset and to convert datetimezone data to local date/time.

In the picture below you can see the input and 3 columns with the result from the formula above (my culture code is set to "en-US"): as datetimezone, as any, as datetime (which converts the datetimezone to the local UTC Offset; in my case, on January 2, 2006 +01:00, so 6 hours behind UTC Offset +07:00 and 8 hours ahead of UTC Offset -07:00).

 

DTZ in PQ and Data Model.png

Specializing in Power Query Formula Language (M)

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

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

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.