Forum Discussion
Formatting Issue (Getting data from 1 column into 7 columns)
You may use Power Query to get the data in the desired format.
To do so, follow these steps...
- Convert your one column Web Data into an Excel Table if not already formatted as an Excel Table and to do that select your data and press Ctrl+T and uncheck the CheckBox for "My table has headers" and click OK.
- Rename the Excel Table you just created with "WebData".
- Now go to Data Tab and under Get & Transform Data group, click on Get Data --> From Other Sources --> Blank Query. This will open Power Query Editor Window.
- On Power Query Editor Window --> View --> and click on Advanced Editor and delete whatever you see that and paste the query given below in the Advanced Editor and click on OK.
- Now go to Home Tab on Power Query Editor Window and click on Close & Load. This will load the table with data in the desired format into a new sheet.
Query:
let
Source = Excel.CurrentWorkbook(){[Name="WebData"]}[Content],
#"Removed Blank Rows" = Table.SelectRows(Source, each not List.IsEmpty(List.RemoveMatchingItems(Record.FieldValues(_), {"", null}))),
#"Changed Type" = Table.TransformColumnTypes(#"Removed Blank Rows",{{"Column1", type any}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1),
#"Inserted Modulo" = Table.AddColumn(#"Added Index", "Modulo", each Number.Mod([Index], 7), type number),
#"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(#"Inserted Modulo", {{"Modulo", type text}}, "en-IN"), List.Distinct(Table.TransformColumnTypes(#"Inserted Modulo", {{"Modulo", type text}}, "en-IN")[Modulo]), "Modulo", "Column1"),
#"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Index"}),
#"Filled Up" = Table.FillUp(#"Removed Columns",{"1", "2", "3", "4", "5", "6"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Up", each ([0] <> null)),
#"Renamed Columns" = Table.RenameColumns(#"Filtered Rows",{{"0", "Company Name"}, {"1", "Industry"}, {"2", "Yearly Revenue"}, {"3", "Phone#"}, {"4", "Location"}, {"5", "Website"}, {"6", "Year Founded"}})
in
#"Renamed Columns"
Also, if you are getting the web data through the From Web under Get & Transformed Data Group, you may tweak the existing query to get the data in the desired format.
- JeffJ625Sep 15, 2019Copper Contributor
Subodh (and Sergei)...thank you very much for responding. I've tried both of your Power Querys and get the same message:
Expression.Error: We couldn't find an Excel table named 'WebData".
Details:
WebData
What am I doing wrong?
- Jeff
- SergeiBaklanSep 16, 2019Diamond Contributor
And much better, if you don't copy/paste from web but query the web, combine transformations suggested here with the initial query. If that's copy/paste perhaps it's worth to try query the web, finally it'll be one click solution - open the file, refresh all.
- Subodh_Tiwari_sktneerSep 15, 2019Silver Contributor
Hi Jeff,
If you look at the points#1 and 2 in my proposed solution, you are supposed to convert your data into an Excel Table and then rename the Excel Table as 'WebData" and then the query will work for you as desired as this query assumes that in your file there is an Excel Table called "WebData" which must be missing at present in your actual file.
To convert your data into an Excel Table, select all your data and then press Ctrl+T and it will convert your data into an Excel Table. Once your data is converted into an Excel Table, a Table Design Tab will appear in the Ribbon and if you click that and look at top right of the ribbon, you will have a TextBox to have Table Name and you can type the WebData in there and hit Enter, that will rename your Table as WebData.
- JeffJ625Sep 16, 2019Copper Contributor
Subodh/Sergei,
Your suggestions have been most helpful. I was finally able to get the data into the right format but it is a tremendous amount of work. I'm working off of a prospect list web site where I have to input the specific parameters for the companies I want to discover (for example, location, industry, yearly revenue, etc.). For large listings, I'm able to see only 25 companies at a time. It looks like this:
I have to copy and paste each grouping of 25 into Excel and all of this info. goes into just one column. When I've finally created a large enough list, I then run the Power Query that you've designed. This is a lot of work because if each company doesn't have the exact same number of data points (in this case 7) the report is all jumbled and I have to go back and find where the missing data should go.
Do you think I'm doing this in the most efficient way or is there a more economical way to go about this task. I don't see how I can pull the info. right off the web site as I work because the web address just shows something like: https://app.uplead.com/#. I'm unsure if Excel can pull the exact info. that I've specifically collated on the site.
You gentlemen have been so very kind in your guidance and I sincerely appreciate it.
Regards,
Jeff
;lkjasdjf
- SergeiBaklanSep 15, 2019Diamond Contributor
WebData is the table with raw data which you shall create. Select all raw data in column A, press Ctrl+T and create the table.
On ribbon you will stay on Table Design
Type here table name now
- SergeiBaklanSep 15, 2019Diamond Contributor
Bit another transformation
let ColumnNames = {"Company Name", "Industry", "Yearly Revenue", "Phone#", "Location", "Website", "Year Founded"}, ItemsInGroup =7, Source = Excel.CurrentWorkbook(){[Name="WebData"]}[Content], RemoveNulls = Table.SelectRows( Source, each not List.IsEmpty( List.RemoveMatchingItems(Record.FieldValues(_), {"", null}) ) ), GroupsToLists = Table.FromList( List.Split( RemoveNulls[Column1], ItemsInGroup ), Splitter.SplitByNothing() ), GroupsToRecords = Table.ReplaceValue( GroupsToLists, each [Column1] , each Record.FromList([Column1],ColumnNames), Replacer.ReplaceValue,{"Column1"} ), ExpandRecords = Table.ExpandRecordColumn( GroupsToRecords, "Column1", ColumnNames, ColumnNames ) in ExpandRecords
- Subodh_Tiwari_sktneerSep 15, 2019Silver Contributor
Good one SergeiBaklan! 👍