cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Anonymous
Not applicable

Combine and clean different excel sheets using PQ

Hi guys i need help on the below:

Am i trying to automate a manual process that is done monthly whereby the datasource is from a folder containing multiple excel sheets. The format that it comes in from is very messy and needs to cleaned. It also has to be dynamic (Eg: whenever a new excel sheet is added into the folder it should be reflected after refreshing). Here is the code so far as well as the final expected end results in the picture below. Ty 

 

let
    Source = Folder.Files("C:\Users\achia\OneDrive - Lenovo\Desktop\Lenovo\Payroll\Data Cleansing"),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each Excel.Workbook([Content])),
    #"Expanded Custom1" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"Name", "Data", "Item", "Kind", "Hidden"}, {"Name.1", "Data", "Item", "Kind", "Hidden"}),
    #"Added Custom1" = Table.AddColumn(#"Expanded Custom1", "Custom", each Table.SelectColumns([Data],{"Column2","Column3","Column4"})),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom.1", each Table.RemoveFirstN([Custom],9)),
    #"Added Custom3" = Table.AddColumn(#"Added Custom2", "Custom.2", each Table.RemoveLastN([Custom.1],17)),
    #"Added Custom4" = Table.AddColumn(#"Added Custom3", "Custom.3", each Table.SelectRows([Custom.2], each [Column4] <> "Yearly"))
in
    #"Added Custom4"

 



Before
adrianchy_1-1654072437084.png


After

adrianchy_2-1654072488408.png

 





 

 

1 ACCEPTED SOLUTION
KT_Bsmart2gethe
Super User
Super User

Hi @Anonymous ,

 

It'd be great if you could share the sample data for a better solution that will meet your expectation (Dynamic).

 

If not, please add a custom column after where you stop, then add the code below (I can only see one table from your screenshot and I assumed the second table or future table come in the same view):

 

Table.AddColumn(Table.RenameColumns(Table.Transpose(Table.FirstN(Table.Transpose(Table.SelectRows([Custom.3], each ([Column4] <> null and [Column4] <> "N/A") and ([Column3] <> null and [Column3] <> "N/A") and ([Column2] = "Basic" or [Column2] = "Variable"))),2)),{{"Column1", "Type"}, {"Column2", "Amount"}}),"Name",(x)=> [Custom.3]{0}[Column4])

 

Regards

KT

View solution in original post

3 REPLIES 3
watkinnc
Super User
Super User

Why don't you do the transformation work in the "Transform" file, so that they will apply to all of the tables in the folder?

 

--Nate


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!
KT_Bsmart2gethe
Super User
Super User

Hi @Anonymous ,

 

It'd be great if you could share the sample data for a better solution that will meet your expectation (Dynamic).

 

If not, please add a custom column after where you stop, then add the code below (I can only see one table from your screenshot and I assumed the second table or future table come in the same view):

 

Table.AddColumn(Table.RenameColumns(Table.Transpose(Table.FirstN(Table.Transpose(Table.SelectRows([Custom.3], each ([Column4] <> null and [Column4] <> "N/A") and ([Column3] <> null and [Column3] <> "N/A") and ([Column2] = "Basic" or [Column2] = "Variable"))),2)),{{"Column1", "Type"}, {"Column2", "Amount"}}),"Name",(x)=> [Custom.3]{0}[Column4])

 

Regards

KT

KT_Bsmart2gethe_0-1654081444542.png

 

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

Thank you 2022 Review

2022 Monthly Feature Releases

We had a great 2022 with a ton of feature releases to help you drive a data culture.

Top Solution Authors
Top Kudoed Authors