SOLVED

Need to convert a text file to Excel - not the typical comma delineated file

Copper Contributor

I have a text file that needs to be converted to Excel however the text is grouped in a fashion that Excel doesn't not convert into columns but exactly as it appears in the text file.  The text content looks like this.  I added an underscore before 'name' to differenciate each group of text.  How can I import to Excel where the text before each : becomes the column heading?

_name: All Company
id: 0
type: internal
privacy_setting: public
state: active
approximate_messages_count: 6
last_message_at: 2014-06-12 09:52:27.259000062 +00:00
o365_connected: false
group_admins: All Yammer Verified admins
member_counts:
internal: 24565
external: 0
uploaded_file_counts:
yammer_files: 0
sharepoint_files: 0
66069:
__name: Marine Matter
id: 66069
type: internal
privacy_setting: public
state: deleted
approximate_messages_count: 70
last_message_at: 2015-10-30 08:31:43.069999000 Z
o365_connected: false
group_admins:
with_o365_creation_rights: []
without_o365_creation_rights: []
member_counts:
internal: 0
external: 0
uploaded_file_counts:
yammer_files: 0
sharepoint_files: 0
89528:
_name: Summers Lab
id: 89528
type: internal
privacy_setting: public
state: deleted
approximate_messages_count: 10
last_message_at: 2012-10-01 11:00:22.418401000 Z
o365_connected: false
group_admins:
with_o365_creation_rights: []
without_o365_creation_rights: []
member_counts:
internal: 0
external: 0
uploaded_file_counts:
yammer_files: 0
sharepoint_files: 0
89758:
_name: Pilot Group
id: 89758
type: internal
privacy_setting: public
state: active
approximate_messages_count: 16
last_message_at: 2011-07-04 09:46:24.989397000 Z
o365_connected: false
group_admins:
with_o365_creation_rights: []
without_o365_creation_rights: []
member_counts:
internal: 0
external: 0
uploaded_file_counts:
yammer_files: 1
sharepoint_files: 0
90435:

15 Replies

@Maria Baker , I used Power Query to accomplish this. I copied your sample into a text file (attached). I changed the delimiter from ":" to ";" since there were dates in the data that used ":". To use this change the location of the source text file in the source table. The processed data will be in the Output tab.

@TheAntony Thank you.  I'm not familiar with power queries...so I'm stuck on this part, "change the location of the source text file in the source table."  Where do I change this?

Thank you

MB

@Maria Baker 

Another variant is attached.

FilenamePath is in the named cell within the sheet, same as in @TheAntony  file.

@Maria Baker 

  •  Download the 2 files I uploaded to your local drive
  • Open the Excel file - "Test Power Query.xlsx"
  • It will open up in the tab named Source
  • Change the File Path in the cell A2 from "C:\Users\dgant\Downloads\test.csv" to the file path of the test.csv file that you down loaded. 
  • Go to the tab named "Output" that shows you the output of PQ
  • Save the xlsx file
  • Open test.csv and add more records (making the appropriate changes I mentioned - using ; as the delimiter instead of :_
  • Save test.csv
  • Hit Data->Refresh All in the Excel file to see the output table updated with the info you put in the csv file

 

Or you can use @Sergei Baklan 's solution. Let us know how it goes.

 

 

 

@TheAntony First thank you very much for the assistance.  My apologies for being so thick......how did you change the delimiter from : to ; in the text file? My original file has 38000 rows.

 

Best Regards

MB

best response confirmed by Maria Baker (Copper Contributor)
Solution

@Maria Baker 

IMHO, it's not necessary to change delimiters, in general it's not necessary to make any changes in your text file. For the delimiters you may use split only on left most delimiter, that won't affect the dates. 

 

Variant of layout as @TheAntony  suggested is in TextTransformTwo query attached.

You can import data from a text file into an existing worksheet.

On the Data tab, in the Get & Transform Data group, click From Text/CSV.

In the Import Data dialog box, locate and double-click the text file that you want to import, and click Import.

In the preview dialog box, you have several options:

Select Load if you want to load the data directly to a new worksheet.

Alternatively, select Load to if you want to load the data to a table, PivotTable/PivotChart, an existing/new Excel worksheet, or simply create a connection. You also have the choice of adding your data to the Data Model.

Select Transform Data if you want to load the data to Power Query, and edit it before bringing it to Excel.

@Smith_J  Thank you for the input.  This is the process I started with - the issue I'm having is understanding how to manipulate the data in power query into multiple columns instead of one column.

Thank you

@Maria Baker 

Please ask if any concrete questions while you check the query step by step.

@Sergei Baklan and @TheAntony - thank you for the assistance on my first request for help.  I was able to get the data per Sergei Baklan's instructions & files.

I have another file that needs to be extracted from one column to multiple columns - for my yammer users which I've attached here.

I tried dissecting your files to understand the queries but that was a fail.  I would be grateful for your assistance again.

Thank you

@Maria Baker 

That's bit another logic of this file. What to do

- since now you have commas within texts, ignore them as default delimiter. That could be done as

= Csv.Document(File.Contents(filePathName),{"Column1"},{0})

which says we split on one Column1 starting from position 0. Other words, no split.

 

- transforming column we select as names not only field starts by _, but also equal to name

Table.AddColumn(Source, "Names", each if Text.StartsWith([Column1.1],"_") or [Column1.1] = "name" then [Column1.2] else null)

and filter them as other fields as

= Table.SelectRows(#"Filled Down", each not ( Text.StartsWith([Column1.1], "_") or [Column1.1]="name"))

 

- since field role could be repeated for same person, we created in the middle intermediate table with this field only

image.png

group it by names and field (Column1.1), extract list with roles and convert it to text:

image.png

after filter field role from main table and append to it above one

 

- datetime text here is without separation of date and time in the text. Thus we remove comma on the end and insert T between date and time

= Table.ReplaceValue(#"Extracted Text Before Delimiter",each [last_date_accessed], each Text.Insert([last_date_accessed],10,"T"),Replacer.ReplaceText,{"last_date_accessed"})

convert now this text on actual datetime.

 

- if in another file there is no field last_date_accessed (as in initial one) error appears. If so correct on proper field name or remove the step. That could be handled automatically, but better to know all possible datetime field names.

 

Please check in attached file.

@Sergei Baklan  YOU are a life saver!  Thank you so much for the detailed explanation and the file.  I'll work with this to better understand these queries.

I greatly appreciate your time & expertise!

@Maria Baker , you are welcome. Please ask if there are more questions.

@Sergei Baklan  Hello! I have been reading up and down this thread since the past two days, as I too have a similar file that I am continuously failing to format. I tried reading into the query steps of the files you guys have provided and apply to my files failing to do so. Could you please help me/ guide me in any way? I am attaching the format of my files below.
I copied the same data multiple times just as an example but this is how the information is going to be laid out for me in a text file. Initially it was the equals to sign '=' instead of the ';' but i replaced it to see if it worked lol. I also tried removing the white spaces. Any kind of help would be highly appreciated! 


                     Linkset index  ;  14

                      Linkset name  ;  GP National

               Link selection mask  ;  B1111

                Adjacent DSP index  ;  14

                          DSP name  ;  GP National

         International network DPC  ;  000000H

International reserved network DPC  ;  000000H

              National network DPC  ;  0011D8H

     National reserved network DPC  ;  000000H

                               OPC  ;  001278H

                          STP flag  ;  False

            Linkset selection mask  ;  B1111

                 Master/Slave type  ;  Master

 

 

                     Linkset index  ;  14

                      Linkset name  ;  GP National

               Link selection mask  ;  B1111

                Adjacent DSP index  ;  14

                          DSP name  ;  GP National

         International network DPC  ;  000000H

International reserved network DPC  ;  000000H

              National network DPC  ;  0011D8H

     National reserved network DPC  ;  000000H

                               OPC  ;  001278H

                          STP flag  ;  False

            Linkset selection mask  ;  B1111

                 Master/Slave type  ;  Master

 

 

 

 

                     Linkset index  ;  14

                      Linkset name  ;  GP National

               Link selection mask  ;  B1111

                Adjacent DSP index  ;  14

                          DSP name  ;  GP National

         International network DPC  ;  000000H

International reserved network DPC  ;  000000H

              National network DPC  ;  0011D8H

     National reserved network DPC  ;  000000H

                               OPC  ;  001278H

                          STP flag  ;  False

            Linkset selection mask  ;  B1111

                 Master/Slave type  ;  Master

@Yamin0724 

Better to have sample of txt file, I'm not sure that text copy/pasted from web has the same format as text file.

If the goal is to receive table like

image.png

the script could be

let
    sep = ";",  // change on actual one
    file = Excel.CurrentWorkbook(){[Name="filepath"]}[Content]{0}[Column1],
    Source = Table.FromColumns({Lines.FromBinary(File.Contents(file), null, null, 1252)}),
    #"Clean text" = Table.SelectRows(Source, each ([Column1] <> "" and [Column1] <> " ")),
    #"Split it" = Table.SplitColumn(
        #"Clean text",
        "Column1",
        Splitter.SplitTextByDelimiter(sep, QuoteStyle.Csv),
        {"Name", "Value"}
    ),
    #"Trim it" = Table.TransformColumns(
        #"Split it",
        {
            {"Name", Text.Trim, type text},
            {"Value", Text.Trim, type text}
        }
    ),
    // in next formula after it generated by "Group By" change in formula bar
    // each _, [...] on each _[Value]
    #"Grouped Rows" = Table.Group(#"Trim it", {"Name"}, {{"Columns", each _[Value]}}),
    // below is manually created step, hope formula is self-explained
    #"Create Table" = Table.FromColumns(#"Grouped Rows"[Columns], #"Grouped Rows"[Name])
in
    #"Create Table"

Please check steps in attached file.

If you mean something else please submit sample text file and Excel with manually created mock-up of the table into which it shall be transformed.

1 best response

Accepted Solutions
best response confirmed by Maria Baker (Copper Contributor)
Solution

@Maria Baker 

IMHO, it's not necessary to change delimiters, in general it's not necessary to make any changes in your text file. For the delimiters you may use split only on left most delimiter, that won't affect the dates. 

 

Variant of layout as @TheAntony  suggested is in TextTransformTwo query attached.

View solution in original post