Power Query - How to align the first value and 2nd value to respective columns

sara121

New Member
Joined
Jul 7, 2022
Messages
23
Office Version
  1. 365
Platform
  1. Windows
I have converted PDF to Excel. For some reasons, the numbers in the row do not align with the header.
In the example below, I expect th first number in th row to be aligned under Column "B". and the 2nd number seen in the row to be aligned under Column "Debit".

Can someone kindly advice how to acheive this using M code?

Thanks.

1684781571454.png
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
You didn't say anything about the Debit value for the first 6 rows, but I will assume if there is no second number, then the Debit will be null (it could be changed to zero at the end).

My approach would be:
  1. Select all columns
  2. Add Column tab - > Merge Columns - Select a separator (I used dash as delimiter below) and you get the Merged column
  3. Remove other columns (or keep them to verify the result).
  4. Select the Merged column, and Home tab -> Split Column -> by delimiter - enter the delimiter you selected. You got the desired result. Change the column data types as you wish (currency maybe?)
Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    MergeColumns = Table.AddColumn(Source, "Merged", each Text.Combine({Text.From([B]), Text.From([Column18]), Text.From([Debit]), Text.From([Column20])}, "-"), type text),
    RemovedOthers = Table.RemoveColumns(MergeColumns,{"B", "Column18", "Debit", "Column20"}),
    SplitColumn = Table.SplitColumn(RemovedOthers, "Merged", Splitter.SplitTextByDelimiter("-", QuoteStyle.Csv), {"B", "Debit"})
in
    SplitColumn
 
Upvote 0
Solution
You didn't say anything about the Debit value for the first 6 rows, but I will assume if there is no second number, then the Debit will be null (it could be changed to zero at the end).

My approach would be:
  1. Select all columns
  2. Add Column tab - > Merge Columns - Select a separator (I used dash as delimiter below) and you get the Merged column
  3. Remove other columns (or keep them to verify the result).
  4. Select the Merged column, and Home tab -> Split Column -> by delimiter - enter the delimiter you selected. You got the desired result. Change the column data types as you wish (currency maybe?)
Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    MergeColumns = Table.AddColumn(Source, "Merged", each Text.Combine({Text.From([B]), Text.From([Column18]), Text.From([Debit]), Text.From([Column20])}, "-"), type text),
    RemovedOthers = Table.RemoveColumns(MergeColumns,{"B", "Column18", "Debit", "Column20"}),
    SplitColumn = Table.SplitColumn(RemovedOthers, "Merged", Splitter.SplitTextByDelimiter("-", QuoteStyle.Csv), {"B", "Debit"})
in
    SplitColumn
Thanks so much!
The Merge Column with dash approach works!! Now I know that the "merge column" would ignore the null value. Thanks so much for the simple solution! Appreciate it!
 
Upvote 0
Thanks so much!
The Merge Column with dash approach works!! Now I know that the "merge column" would ignore the null value. Thanks so much for the simple solution! Appreciate it!
You're welcome. Glad to hear it helped.

Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,350
Messages
6,171,578
Members
452,411
Latest member
colpie

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