|
| 1 | +let |
| 2 | + /* the original question: <https://www.reddit.com/r/PowerBI/comments/1g9qmkl/how_do_i_convert_datetime_to_date_and_ignore_text/> |
| 3 | + |
| 4 | + this souce is from: <https://github.com/ninmonkey/ninMonkQuery-examples/tree/main/forumQuestions/pq> |
| 5 | + */ |
| 6 | + Json = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwMtI1ACJDBUMjKwMDpVgdVEFjJEFjqKCBKUywNC87L788D8wuzs9NVUhKTFHIzCsoLQELQSVjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [RawText = _t]), |
| 7 | + |
| 8 | + Source = Table.TransformColumnTypes( Json, {{"RawText", type text}} ), |
| 9 | + /* |
| 10 | + |
| 11 | + return type: #date, null, or throws |
| 12 | + Inputs: [ "2022-02-01 13:00", "unknown", or invalid ] |
| 13 | + output: [ #date(2022, 02, 01), null, error ] |
| 14 | + |
| 15 | + Columns contain datetimes in en-us formats. Convert them to dates. |
| 16 | + If they fail, check if they are unknown. if yes, return null. do not error. |
| 17 | + If everything else failed, then it's a true error. raise them so you don't accidentally |
| 18 | + convert values to null when they should be errors. |
| 19 | + |
| 20 | + */ |
| 21 | + FromDateOrUnknown = ( string as text ) as nullable date => |
| 22 | + let |
| 23 | + dt = DateTime.FromText( string, [ Culture = "en-us", Format = null ] ), |
| 24 | + return = |
| 25 | + try DateTime.Date( dt ) |
| 26 | + catch (err) => |
| 27 | + if Text.Contains( string, "unknown", Comparer.OrdinalIgnoreCase ) |
| 28 | + then null |
| 29 | + else error err |
| 30 | + in |
| 31 | + return, |
| 32 | + |
| 33 | + Final = Table.TransformColumns( |
| 34 | + Source, |
| 35 | + { |
| 36 | + { "RawText", each FromDateOrUnknown(_), Date.Type } |
| 37 | + }) |
| 38 | + |
| 39 | +in Final |
0 commit comments