cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
DLROLLINGS
Helper I
Helper I

COMBINE TABLES AND COLUMNS

Firstly I would like to start this with saying I have a headache, a literally one. 

 

I have been asked to report on some data that, if I have my way, I would completely rewrite how they are recording the data. The basic principle is there are 120 spreadsheets in a Sharepoint Location that I need to combine. They are in 3 seperate folders and are all uniformed in the approach so simple enough...however the data tables as as below:

 

Property AddressOpt in Waiver Received DateOpt in Review Date (Waiver plus 6 month)WC 04/10/21WC 11/10/21WC 18/10/21
Address 106/06/202106/12/202106/10/2021DD/MM/YYYY21/10/2021
Address 2 NullDD/MM/YYYYDD/MM/YYYY21/10/2021

 

The WC dates continue for the full quarter of the year. I can combine all of the sheets within each folder using Power Query easily enough but then I get stuck. What I need to do from here is combine all of the data but in a means that makes much more sense.

 

Property AddressOpt in Waiver Received DateWaiver Review DateContact Due WeekContact Made
Address 106/06/2021

06/12/2021

04/10/202106/10/2021
Address 106/06/202106/12/202111/10/2021 
Address 106/06/202106/12/202118/10/202121/10/2021
Address 2  04/10/2021 
Address 2  11/10/2021 
Address 2  18/10/202121/10/2021

 

Any ideas on how I can achieve this? I have looked at UNION(SUMMARIZE...) but could not figure out how I combine 13 columns from 3 different sheet into 1 table whilst replicating every address and adding all relevant data.

 

Any help would be most appreciated. I have built an excel VBA that could do this for me but I would rather not have additional steps involved and would like to link direct to Power Bi so that I can automate the refresh. 

1 ACCEPTED SOLUTION
CNENFRNL
Community Champion
Community Champion

No point resorting to DAX for dataset transformation given that PQ handles it with ease,

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WckxJKUotLlYwVNJRMtM30zcyMIIwDY2Q2AYwtouLvq+vfiQQADlGhnCZWB2EUUZAKQhCUY1TaywA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Property Address" = _t, #"Opt in Waiver Received Date" = _t, #"Opt in Review Date (Waiver plus 6 month)" = _t, #"WC 04/10/21" = _t, #"WC 11/10/21" = _t, #"WC 18/10/21" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Opt in Waiver Received Date", type date}, {"Opt in Review Date (Waiver plus 6 month)", type date}}, "de"),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Property Address", "Opt in Waiver Received Date", "Opt in Review Date (Waiver plus 6 month)"}, "Contact Due Week", "Contact Made"),
    Xform = Table.TransformColumns(#"Unpivoted Columns", {{"Contact Due Week", each Date.From(Text.Select(_, {"0".."9","/"}), "fr")}, {"Contact Made", each try Date.From(_, "fr") otherwise null}})
in
    Xform

Screenshot 2021-11-27 032129.png

View solution in original post

1 REPLY 1
CNENFRNL
Community Champion
Community Champion

No point resorting to DAX for dataset transformation given that PQ handles it with ease,

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WckxJKUotLlYwVNJRMtM30zcyMIIwDY2Q2AYwtouLvq+vfiQQADlGhnCZWB2EUUZAKQhCUY1TaywA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Property Address" = _t, #"Opt in Waiver Received Date" = _t, #"Opt in Review Date (Waiver plus 6 month)" = _t, #"WC 04/10/21" = _t, #"WC 11/10/21" = _t, #"WC 18/10/21" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Opt in Waiver Received Date", type date}, {"Opt in Review Date (Waiver plus 6 month)", type date}}, "de"),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Property Address", "Opt in Waiver Received Date", "Opt in Review Date (Waiver plus 6 month)"}, "Contact Due Week", "Contact Made"),
    Xform = Table.TransformColumns(#"Unpivoted Columns", {{"Contact Due Week", each Date.From(Text.Select(_, {"0".."9","/"}), "fr")}, {"Contact Made", each try Date.From(_, "fr") otherwise null}})
in
    Xform

Screenshot 2021-11-27 032129.png

Helpful resources

Announcements
2022 Release Wave 1 760x460.png

2022 Release Wave 1 Plan

Power Platform release plan for the 2022 release wave 1 describes all new features releasing from April 2022 through September 2022.

Power BI December 2021 Update_carousel 768x460.jpg

Check it Out!

Click here to read more about the December 2021 Updates!

Top Solution Authors