cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Helper I
Helper I

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

Accepted Solutions
Highlighted
Super User IV
Super User IV

Re: Extracting information from a string of text from outlook ICS File

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.


---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

2 REPLIES 2
Highlighted
Super User IV
Super User IV

Re: Extracting information from a string of text from outlook ICS File

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?


---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Highlighted
Super User IV
Super User IV

Re: Extracting information from a string of text from outlook ICS File

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.


---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

Helpful resources

Announcements
August 2020 Community Challenge: Can You Solve These?

August 2020 Community Challenge: Can You Solve These?

We're excited to announce our first cross-community 'Can You Solve These?' challenge!

Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Community Summit Australia – Join Online!

Community Summit Australia – Join Online!

Be a part of the leading Microsoft Business Applications digital event, curated for the APAC community.

Top Solution Authors
Top Kudoed Authors