March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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
After
Solved! Go to Solution.
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
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
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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
21 | |
16 | |
13 | |
13 | |
9 |
User | Count |
---|---|
36 | |
31 | |
20 | |
19 | |
17 |