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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Priscila_Gr
Frequent Visitor

UTC to local time of transaction

Priscila_Gr_0-1672744655160.png

Priscila_Gr_1-1672744725482.png

Hello,

All transactions are recorded in UTC time and I would like to transform the dt_email_sent column into the local time, I created a table with all the time zones considering the country and merged with the main table where I have the date that the email was sent.

I would like help on which functions to use to add or subtract hours and thus arrive at the local time that the email was sent. I've tried converting to decimals but unfortunately it didn't work.

Any thoughts?

 

2 ACCEPTED SOLUTIONS
johnt75
Super User
Super User

You would need to split out the +/- sign into a separate column but then you could create a calculated column like

Local Time =
VAR OffsetSign =
    LOOKUPVALUE (
        'Time conversion'[Sign],
        'Time conversion'[Timezone], 'Table'[Timezone]
    )
VAR OffsetValue =
    LOOKUPVALUE (
        'Time conversion'[Offset value],
        'Time conversion'[Timezone], 'Table'[Timezone]
    )
VAR Result =
    IF (
        OffsetSign = "+",
        'Table'[UTC time] + TIMEVALUE ( OffsetValue ),
        'Table'[UTC time] - TIMEVALUE ( OffsetValue )
    )
RETURN
    Result

View solution in original post

v-rongtiep-msft
Community Support
Community Support

Hi @Priscila_Gr ,

You can refer to below steps to create columns to switch datetime.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dZAxDsMwDAP/krkuKMl2bL7DU438IOjW/zduhqaNAmgQQPBEsfdJISUgB0iTSgOhdwCPabn16fla14tl96Vg0lSYKqV+fUdo/kDhi5GbjvgvpiClqRLGKE6cI6IwzTTz+TNj+eG7iEzBNucUtpcSCXEjig3R1D9eOV7IZ6eW0Rmi0/XyBg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [UTC = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"UTC", type datetimezone}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "LocalTimeZone", each if [UTC]<> null then DateTimeZone.SwitchZone([UTC], Number.From(DateTimeZone.ZoneHours(DateTimeZone.LocalNow()))) else null),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Datetime", each DateTime.From([UTC])),
    #"Changed Type1" = Table.TransformColumnTypes(#"Added Custom1",{{"UTC", type text}, {"LocalTimeZone", type text}, {"Datetime", type datetime}})
in
    #"Changed Type1"

 

vpollymsft_0-1672810658848.png

 

 

I have also found a helpful blog, please refer to it to see if it helps you.

Convert UTC date format into local time format in Power BI - Microsoft Dynamics CRM Community

 

How to Get Your Question Answered Quickly 

 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .

 

Best Regards
Community Support Team _ Polly

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

View solution in original post

2 REPLIES 2
v-rongtiep-msft
Community Support
Community Support

Hi @Priscila_Gr ,

You can refer to below steps to create columns to switch datetime.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dZAxDsMwDAP/krkuKMl2bL7DU438IOjW/zduhqaNAmgQQPBEsfdJISUgB0iTSgOhdwCPabn16fla14tl96Vg0lSYKqV+fUdo/kDhi5GbjvgvpiClqRLGKE6cI6IwzTTz+TNj+eG7iEzBNucUtpcSCXEjig3R1D9eOV7IZ6eW0Rmi0/XyBg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [UTC = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"UTC", type datetimezone}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "LocalTimeZone", each if [UTC]<> null then DateTimeZone.SwitchZone([UTC], Number.From(DateTimeZone.ZoneHours(DateTimeZone.LocalNow()))) else null),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Datetime", each DateTime.From([UTC])),
    #"Changed Type1" = Table.TransformColumnTypes(#"Added Custom1",{{"UTC", type text}, {"LocalTimeZone", type text}, {"Datetime", type datetime}})
in
    #"Changed Type1"

 

vpollymsft_0-1672810658848.png

 

 

I have also found a helpful blog, please refer to it to see if it helps you.

Convert UTC date format into local time format in Power BI - Microsoft Dynamics CRM Community

 

How to Get Your Question Answered Quickly 

 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .

 

Best Regards
Community Support Team _ Polly

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

johnt75
Super User
Super User

You would need to split out the +/- sign into a separate column but then you could create a calculated column like

Local Time =
VAR OffsetSign =
    LOOKUPVALUE (
        'Time conversion'[Sign],
        'Time conversion'[Timezone], 'Table'[Timezone]
    )
VAR OffsetValue =
    LOOKUPVALUE (
        'Time conversion'[Offset value],
        'Time conversion'[Timezone], 'Table'[Timezone]
    )
VAR Result =
    IF (
        OffsetSign = "+",
        'Table'[UTC time] + TIMEVALUE ( OffsetValue ),
        'Table'[UTC time] - TIMEVALUE ( OffsetValue )
    )
RETURN
    Result

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors