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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

force line break in text file to not create new row

Is it possible to import a text file and interpret it as a single data point. i.e. Line breaks not creating new rows, but just interpret it as one very long string?

 

Alternatively, or similarly, if I have a table with lots of rows, is there a simple way to collapse all values from all rows into the first row with line breaks instead of new rows?

2 ACCEPTED SOLUTIONS
MarcelBeug
Community Champion
Community Champion

Yes. it can be done.

 

As far as I know (and that's pretty far nowadays) there is only 1 way to import a text file into a single field using the menu-options:

1. Get files from folder.

2. Remove all files and columns you don't need.

3. Right-click the Content column - Transform - Text.

You may want to turn on "Show Whitespace" in the View menu.

 

The other question: it can be done with Lines.ToText, but only via the Formula bar or the Advanced Editor.

 

Watch this video for an example in which the following code was generated:

 

let
    // Step 1: binary to 1 field (per file):
    Source = Folder.Files("C:\Users\Marcel\OneDrive - Bemint\Office 365\Power Query\Binary"),
    #"Filtered Rows" = Table.SelectRows(Source, each ([Extension] = ".txt")),
    #"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows",{"Content"}),
    #"Transformed Column" = Table.TransformColumns(#"Removed Other Columns",{},Text.FromBinary),

    // Step 2: combine textfields in 1 field:
    Custom1 = Lines.ToText(#"Transformed Column"[Content]),
    #"Converted to Table" = #table(1, {{Custom1}})
in
    #"Converted to Table"
Specializing in Power Query Formula Language (M)

View solution in original post

Anonymous
Not applicable

I did find a workaround, which required mild M editing. I'll summarize here for posterity. 

 

When I point PowerBI to a text file, I get a table of single column with however many rows as I have lines in the source file. (I did try interpreting this file as .csv with option to "Ignore Line Breaks" but that didn't work, in spite of it looking like exactly what I want. *shrug*). Step one, after file is sourced, it to transpose. Step Two is to Merge columns, with a space in between. There is only one trick here: when you don't know the number of rows in advance, you won't know how many (or which) columns to merge. In my case, I want them all merged, though, so I just introduced an intermediate step from advanced editor that returns a list of all my column names, then passed that to the Merge command instead of the static list generated by the UI.

 

This is how it came out:

 

let
  Source = Csv.Document(File.Contents("C:\myFilePath\myFileName"),[Delimiter=";", QuoteStyle=QuoteStyle.Csv]),
  #"Transposed Table" = Table.Transpose(Source),
  ColumnNames = Table.ColumnNames(#"Transposed Table"),
  #"Merged Columns" = Table.CombineColumns(#"Transposed Table",ColumnNames,Combiner.CombineTextByDelimiter(" ", QuoteStyle.None),"NameOfMySingleColumn"),

in
  #"Merged Columns"

View solution in original post

4 REPLIES 4
DanMandle
Frequent Visitor

Related question to this thread from long-ago:
How does one force the text in the rows of a table in Power BI to only show a certain number of characters and then end with a truncation symbol (i.e., "..")?
The hard code solution is to make a new column =(LEFT(table[field]),characters). But how to make it dynamic based on how wide the user might wish to make their columns when they click and drag column headers?


Anonymous
Not applicable

I did find a workaround, which required mild M editing. I'll summarize here for posterity. 

 

When I point PowerBI to a text file, I get a table of single column with however many rows as I have lines in the source file. (I did try interpreting this file as .csv with option to "Ignore Line Breaks" but that didn't work, in spite of it looking like exactly what I want. *shrug*). Step one, after file is sourced, it to transpose. Step Two is to Merge columns, with a space in between. There is only one trick here: when you don't know the number of rows in advance, you won't know how many (or which) columns to merge. In my case, I want them all merged, though, so I just introduced an intermediate step from advanced editor that returns a list of all my column names, then passed that to the Merge command instead of the static list generated by the UI.

 

This is how it came out:

 

let
  Source = Csv.Document(File.Contents("C:\myFilePath\myFileName"),[Delimiter=";", QuoteStyle=QuoteStyle.Csv]),
  #"Transposed Table" = Table.Transpose(Source),
  ColumnNames = Table.ColumnNames(#"Transposed Table"),
  #"Merged Columns" = Table.CombineColumns(#"Transposed Table",ColumnNames,Combiner.CombineTextByDelimiter(" ", QuoteStyle.None),"NameOfMySingleColumn"),

in
  #"Merged Columns"
MarcelBeug
Community Champion
Community Champion

Yes. it can be done.

 

As far as I know (and that's pretty far nowadays) there is only 1 way to import a text file into a single field using the menu-options:

1. Get files from folder.

2. Remove all files and columns you don't need.

3. Right-click the Content column - Transform - Text.

You may want to turn on "Show Whitespace" in the View menu.

 

The other question: it can be done with Lines.ToText, but only via the Formula bar or the Advanced Editor.

 

Watch this video for an example in which the following code was generated:

 

let
    // Step 1: binary to 1 field (per file):
    Source = Folder.Files("C:\Users\Marcel\OneDrive - Bemint\Office 365\Power Query\Binary"),
    #"Filtered Rows" = Table.SelectRows(Source, each ([Extension] = ".txt")),
    #"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows",{"Content"}),
    #"Transformed Column" = Table.TransformColumns(#"Removed Other Columns",{},Text.FromBinary),

    // Step 2: combine textfields in 1 field:
    Custom1 = Lines.ToText(#"Transformed Column"[Content]),
    #"Converted to Table" = #table(1, {{Custom1}})
in
    #"Converted to Table"
Specializing in Power Query Formula Language (M)
Anonymous
Not applicable

Did you make that video just for me?!? I'm touched!

 

Thanks for the pointer. Totally different approach to what I wound up with, but appears to work as well, though it's a few more clicks. 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.