Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
I am looking to import a list of transaction records from a CSV. There are 100+ columns with various parameters, some of the columns represent specific DateTime values related to the transaction (start time, end time, etc.) and are in the (admittedly odd) format:
"ddMMMyy:HH:mm:ss" (e.g. 01SEP22:22:15:00)
At the moment, Power BI imports these columns as text. I would like these columns to be recognised as DateTime so I can use them in reports.
I have found a method from this forum to add a new column (EVENT_TIME_PBI) by approprately parsing the original column (EVENT_TIME):
#"Added Custom1" = Table.AddColumn(#"Added Custom", "EVENT_TIME_PBI", each DateTime.FromText([EVENT_TIME], [Format="ddMMMyy:HH:mm:ss"])),
and have confirmed this works to provide the EVENT_TIME_PBI as DateTime type.
What I want to have, however, is no extraneous columns and the EVENT_TIME column containing the correctly-formatted DateTime data, as the column name is well-known to report users.
Is there a way to either: specify the format of the DateTime data for the import; or perform the post-import conversion 'in place'?
Solved! Go to Solution.
For in-place conversion, insert this step
= Table.ReplaceValue(Source, each [EVENT_TIME], each DateTime.FromText([EVENT_TIME], [Format="ddMMMyy:HH:mm:ss"]), Replacer.ReplaceValue, {"EVENT_TIME"})
Code for testing
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSlTSUTIwDHYNMDKyAiJDUysDA6VYnWilJKCEkaG/c4iRsZUhskQyUMLQ0MvRD6jcAKgJIhELAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, EVENT_TIME = _t]),
Custom1 = Table.ReplaceValue(Source, each [EVENT_TIME], each DateTime.FromText([EVENT_TIME], [Format="ddMMMyy:HH:mm:ss"]), Replacer.ReplaceValue, {"EVENT_TIME"})
in
Custom1
Thanks very much for the quick and detailed response @Vijay_A_Verma .
As seems to always be the case, I also managed to build an alternate solution via:
#"Parsed Dates" = Table.TransformColumns(#"Promoted Headers", {
{"EVENT_TIME", each DateTime.FromText(_, [Format="ddMMMyy:HH:mm:ss"]), type datetime},
{"EVENT_TIME_END", each DateTime.FromText(_, [Format="ddMMMyy:HH:mm:ss"]), type datetime}
})
Would there be a functional difference in the two approaches?
For in-place conversion, insert this step
= Table.ReplaceValue(Source, each [EVENT_TIME], each DateTime.FromText([EVENT_TIME], [Format="ddMMMyy:HH:mm:ss"]), Replacer.ReplaceValue, {"EVENT_TIME"})
Code for testing
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSlTSUTIwDHYNMDKyAiJDUysDA6VYnWilJKCEkaG/c4iRsZUhskQyUMLQ0MvRD6jcAKgJIhELAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, EVENT_TIME = _t]),
Custom1 = Table.ReplaceValue(Source, each [EVENT_TIME], each DateTime.FromText([EVENT_TIME], [Format="ddMMMyy:HH:mm:ss"]), Replacer.ReplaceValue, {"EVENT_TIME"})
in
Custom1
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
15 | |
12 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
13 | |
8 | |
7 | |
6 |