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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Extracting information from a string of text from outlook ICS File

Quick bit of help which will enable me to do the rest of the job needed - I'm new to BI, on my 4th day using DAX.

 

I've managed to import and parsed an ICS file to provide me with columns of ICS data.  An example of the column text I'm interested in is below:

 

UID:Bloggs, Fred2014-12-19T00:00:00.0000000Z2014-12-20T00:00:00.0000000Z@acme.inc

 

I'm interested in extracting: Bloggs, Fred (Name)

2014-12-19 (Holiday Start)

2014-12-20 (Holiday End)

 

There's lots other stuff I'm interested in the file I need to cut the info out and store into columns, but if someone could help me with the above, I can probably do the rest myself.

1 ACCEPTED SOLUTION
Greg_Deckler
Super User
Super User

Here is a potential Power Query solution:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCvV0sXLKyU9PL9ZRcCtKTTEyMDTRNTTSNbQMMTCwAiM9AwiIgskZGWDKOSQm56bqZeYlK8XGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Extracted Text After Delimiter" = Table.TransformColumns(#"Changed Type", {{"Column1", each Text.AfterDelimiter(_, "UID:"), type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Text After Delimiter", "Column1", Splitter.SplitTextByDelimiter("T00:", QuoteStyle.Csv), {"Column1.1", "Column1.2", "Column1.3"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Column1.1", type text}, {"Column1.2", type text}, {"Column1.3", type text}}),
    #"Split Column by Position" = Table.SplitColumn(#"Changed Type1", "Column1.1", Splitter.SplitTextByPositions({0, 10}, true), {"Column1.1.1", "Column1.1.2"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Position",{{"Column1.1.1", type text}, {"Column1.1.2", type date}}),
    #"Split Column by Position1" = Table.SplitColumn(#"Changed Type2", "Column1.2", Splitter.SplitTextByPositions({0, 10}, true), {"Column1.2.1", "Column1.2.2"}),
    #"Changed Type3" = Table.TransformColumnTypes(#"Split Column by Position1",{{"Column1.2.1", type text}, {"Column1.2.2", type date}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type3",{"Column1.2.1", "Column1.3"})
in
    #"Removed Columns"

Depends on dates being 10 digits.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

2 REPLIES 2
Greg_Deckler
Super User
Super User

Here is a potential Power Query solution:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCvV0sXLKyU9PL9ZRcCtKTTEyMDTRNTTSNbQMMTCwAiM9AwiIgskZGWDKOSQm56bqZeYlK8XGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Extracted Text After Delimiter" = Table.TransformColumns(#"Changed Type", {{"Column1", each Text.AfterDelimiter(_, "UID:"), type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Text After Delimiter", "Column1", Splitter.SplitTextByDelimiter("T00:", QuoteStyle.Csv), {"Column1.1", "Column1.2", "Column1.3"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Column1.1", type text}, {"Column1.2", type text}, {"Column1.3", type text}}),
    #"Split Column by Position" = Table.SplitColumn(#"Changed Type1", "Column1.1", Splitter.SplitTextByPositions({0, 10}, true), {"Column1.1.1", "Column1.1.2"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Position",{{"Column1.1.1", type text}, {"Column1.1.2", type date}}),
    #"Split Column by Position1" = Table.SplitColumn(#"Changed Type2", "Column1.2", Splitter.SplitTextByPositions({0, 10}, true), {"Column1.2.1", "Column1.2.2"}),
    #"Changed Type3" = Table.TransformColumnTypes(#"Split Column by Position1",{{"Column1.2.1", type text}, {"Column1.2.2", type date}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type3",{"Column1.2.1", "Column1.3"})
in
    #"Removed Columns"

Depends on dates being 10 digits.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
Greg_Deckler
Super User
Super User

Not sure if that is enough sample data to ensure a good solution. That is some very tough text to parse and the solution will depend on whether the date text is always 2 digit months and days. Is it?

 

I assume you want this as a DAX solution and not Power Query?


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.