in power query, add a blank row with a change in value

DrDebit

Board Regular
Joined
May 20, 2013
Messages
123
Office Version
  1. 365
Platform
  1. Windows
I have a table of transactions with sales people that is cleaned and sorted so all transactions for a sales person are together in column A. In PQ, I would like to insert a blank row after each change in agent....similar to the subtotal function in Excel, except I would like to add a blank row to improve readability. Is it possible? Thank you so much in advance.
 
I know this is 3 years later, but I believe this technique would have been relevant then as it is now.
Instead of trying to null all the field values, you can use a Table.Combine() and only null 1 field as the rest of the fields will null automatically.
So, the query would look like this:

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    fnInsertNullRow = (TblRef as table) as table =>
        let     
            TblWithBlankRow =Table.Combine({TblRef, #table(List.FirstN(Table.ColumnNames(TblRef),1),{{null}})})
        in
            TblWithBlankRow,

    Grp  = Table.Group(Source, {"Name"}, {{"Tbl", each _, type table}}, GroupKind.Global),
    TransformCol = Table.TransformColumns(Table.SelectColumns(Grp, {"Tbl"}), {{"Tbl", fnInsertNullRow}}),

    FinalResult = Table.ExpandTableColumn(TransformCol, "Tbl", Table.ColumnNames(TransformCol{0}[Tbl]))

in
    FinalResult

Alternately, you could combined the blank row in the group statement, and wrap that in in the Table.SelectColumns() as such:

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    GrpInsert = Table.SelectColumns(Table.Group(Source, {"Name"}, {{"Tbl", each Table.Combine({_, #table(List.FirstN(Table.ColumnNames(_),1),{{null}})}), type table}}, GroupKind.Global),{"Tbl"}),
    ExpandeTbl = Table.ExpandTableColumn(GrpInsert, "Tbl", {"Name", "Amount"}, {"Name", "Amount"})
in
    ExpandeTbl
 
Upvote 0

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

Forum statistics

Threads
1,215,108
Messages
6,123,133
Members
449,098
Latest member
Doanvanhieu

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