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
smjzahid
Helper V
Helper V

How do I remove non date time values from Date Time columns

I have a column as DateTime which is connected to excel files and users have keyed in TEXT value in source excel file.

 

This will keep happening again and again, How do I write a logic in Power Query that converts all TEXT values entered in this column to null

 

image.png

1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

Do a transformation step on your column and then tweak the code to look like this:

= Table.TransformColumns(Source, {{"Planned Finish Date & Time",
    each try DateTime.FromText(_) otherwise null, type datetime}})

 

Here's a full code sample you can paste into the Advanced Editor:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwMtI1MNQ1MA0xMLYyNrYyNNIzMjU3AAKlWJ1oJTARklpRohQbCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Planned Finish Date & Time" = _t]),
    #"Text to Nulls" = Table.TransformColumns(Source,{{"Planned Finish Date & Time", each try DateTime.FromText(_) otherwise null, type datetime}})
in
    #"Text to Nulls"

View solution in original post

2 REPLIES 2
v-eqin-msft
Community Support
Community Support

Hi @smjzahid ,

 

You could follow @AlexisOlson 's suggestion to use error handling function Try... Otherwise

Or add a replaced error step after changing type:

Eyelyn9_1-1641889992626.png

Eyelyn9_2-1641890018881.png

 

 

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

AlexisOlson
Super User
Super User

Do a transformation step on your column and then tweak the code to look like this:

= Table.TransformColumns(Source, {{"Planned Finish Date & Time",
    each try DateTime.FromText(_) otherwise null, type datetime}})

 

Here's a full code sample you can paste into the Advanced Editor:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwMtI1MNQ1MA0xMLYyNrYyNNIzMjU3AAKlWJ1oJTARklpRohQbCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Planned Finish Date & Time" = _t]),
    #"Text to Nulls" = Table.TransformColumns(Source,{{"Planned Finish Date & Time", each try DateTime.FromText(_) otherwise null, type datetime}})
in
    #"Text to Nulls"

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.

Top Solution Authors
Top Kudoed Authors