shorten 12 columns into 7 required columns using Power Query

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Hello,

try this

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(Source, {"Driver Name", "Driver ID", "Bus Number", "Bus Capacity"}, "Attribute", "Value"),
    #"Added Conditional Column" = Table.AddColumn(#"Unpivoted Columns", "Custom", each if Text.Contains([Attribute], "Students") then [Value] else null ),
    #"Added Conditional Column1" = Table.AddColumn(#"Added Conditional Column", "Custom.1", each if [Custom] = null then [Value] else null ),
    #"Removed Columns" = Table.RemoveColumns(#"Added Conditional Column1",{"Value"}),
    #"Filled Down" = Table.FillDown(#"Removed Columns",{"Custom.1"}),
    #"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Custom] <> null)),
    #"Replaced Value" = Table.ReplaceValue(#"Filtered Rows"," Students","",Replacer.ReplaceText,{"Attribute"}),
    #"Renamed Columns" = Table.RenameColumns(#"Replaced Value",{{"Attribute", "School Type"}, {"Custom.1", "School Name"}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns",{"Driver Name", "Driver ID", "Bus Number", "Bus Capacity", "School Type", "School Name", "Custom"}),
    Finish = Table.RenameColumns(#"Reordered Columns",{{"Custom", "Total Students"}})
in
    Finish
 
Upvote 0
Wow! Thank you so much. That's exactly what I wanted. Is it possible to show me how you did it because I am not that familiar with coding.
 
Upvote 0
Wow! Thank you so much. That's exactly what I wanted. Is it possible to show me how you did it because I am not that familiar with coding.


Hello again,
Glad for you!


1) select "Driver Name", "Driver ID", "Bus Number", "Bus Capacity" and go to
Transform/UnpivotOtherColumns
2) Double click :Added Conditional Column" and you'll see the inside of this step
3) same as step 2
4) select "Value" column and right click - Remove
5) select "Custom.1" column go to Transform/Fill down
6) from "Custom" column uncheck "null"
7) "Attribute" column "Transform" use "Replace values" replace "Students" with nothing (double click "Replace Value step and see its inside")
 
Last edited:
Upvote 0
Hi Aydin :)
Please, check result for these Driver IDs below and compare it with raw data.
29203
46300
30751
35901
Regards :)
 
Upvote 0
Billszysz, you are right, these driver IDs data is different than the raw data.
And I am worried about my data because I don't want any mistake there.
So please help me solve the issue.
Thanks!!
 
Upvote 0
Billszysz, you are right, these driver IDs data is different than the raw data.
And I am worried about my data because I don't want any mistake there.
So please help me solve the issue.
Thanks!!

Hi again,
Yes both you and Billszysz are right for this case. But I thout that the most probably you'll correct your (ugly data :)) data because it is pretty enough and clear that the both options "Students names" and " Number of Students" should be filled in. But in your table there are some of numbers without names and also some names without numbers. And that is why you encounter with this issue. If you've any conditions then you may ask of cource :)
 
Upvote 0
As I've mentioned above your data seems to be ugly. But if you want to adapt the current table (for me there aren't any logic) data then follow this solution - if your data will not be not filled as a fully.
(in result you'll get 71 rows)
Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(Source, {"Driver Name", "Driver ID", "Bus Number", "Bus Capacity"}, "Attribute", "Value"),
    #"Duplicated Column" = Table.DuplicateColumn(#"Unpivoted Columns", "Attribute", "Attribute - Copy"),
    #"Replaced Value" = Table.ReplaceValue(#"Duplicated Column"," Students","",Replacer.ReplaceText,{"Attribute - Copy"}),
    #"Renamed Columns" = Table.RenameColumns(#"Replaced Value",{{"Attribute - Copy", "St_Types"}}),
    #"Grouped Rows" = Table.Group(#"Renamed Columns", {"Driver ID", "St_Types"}, {{"Gr", each if Table.RowCount(Table.FillDown(Table.AddColumn(_, "Fill_Down", each if Value.Is([Value], type number) then null else [Value]),{"Fill_Down"}))=2 then Table.RemoveFirstN(Table.FillDown(Table.AddColumn(_, "Fill_Down", each if Value.Is([Value], type number) then null else [Value]),{"Fill_Down"}),1) else Table.FillDown(Table.AddColumn(_, "Fill_Down", each if Value.Is([Value], type number) then null else [Value]),{"Fill_Down"})  , type table}}),
    #"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"Driver ID"}),
    #"Expanded Gr" = Table.ExpandTableColumn(#"Removed Columns", "Gr", {"Attribute", "Bus Capacity", "Bus Number", "Driver ID", "Driver Name", "Fill_Down", "St_Types", "Value"}, {"Attribute", "Bus Capacity", "Bus Number", "Driver ID", "Driver Name", "Fill_Down", "St_Types.1", "Value"}),
    #"Removed Columns1" = Table.RemoveColumns(#"Expanded Gr",{"St_Types.1"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns1",{"Driver Name", "Driver ID", "Bus Number", "Bus Capacity", "St_Types", "Fill_Down", "Value"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Value", Int64.Type}}),
    #"Replaced Errors" = Table.ReplaceErrorValues(#"Changed Type", {{"Value", null}}),
    Finish = Table.RenameColumns(#"Replaced Errors",{{"St_Types", "Student_Type"}, {"Fill_Down", "Student_Name"}, {"Value", "Total_Student"}})
in
    Finish
 
Last edited:
Upvote 0
I am grateful to both of you.
I wanted to learn a technique how to apply a power query so I provided a sample table with just 12 columns but now here I have an actual table with too many columns which I want to apply a query on. I applied what you guys guided me in the previous replies but I didn’t get the correct results.
I don’t want to take up your time but I would like to guide me once again.
Here is my new workbook: https://drive.google.com/file/d/0B9uKuwzDH_rQRnNfcEMzRmJGNGs/view?usp=sharing
Thanks!
 
Upvote 0

Forum statistics

Threads
1,213,562
Messages
6,114,322
Members
448,564
Latest member
ED38

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top