cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
PhilippeMuniesa
Helper III
Helper III

TCD from Database

Hello,

 

I try to reproduce a technique that Smauro proposed to me in this forum

 

( https://community.powerbi.com/t5/Power-Query/Dynamic-Table-group/m-p/1228146#M39657 ) ,

 

but I am looking to get text and not a sum as in the original case.

 

From a table including an Extract below (4 items Extract),

 

N°SS                      Rubrique                      Valeur

'1550425056002'S21.G00.30.0011234567891234'
'1550425056002'S21.G00.30.002BOURGEATEAU
'1550425056002'S21.G00.30.004'Philippe'
'1550425056002'S21.G00.30.006'01041955'
'1550425056002'S21.G00.30.007'BESANCON'
'1550425056002'S21.G00.30.008'21 route de Gouarec'
'1550425056002'S21.G00.30.009'22110'
'1550425056002'S21.G00.30.010MARSEILLES
'1550425056002'S21.G00.30.013'01'
'1550425056002'S21.G00.30.014'25'
'1550425056002'S21.G00.30.015'FR'
'1550425056002'S21.G00.30.019'92000265'
'1550425056002'S21.G00.40.001'01061987'
'1550425056002'S21.G00.40.002'04'
'1550425056002'S21.G00.40.003'98'
'1550425056002'S21.G00.40.004'344a'
'1550425056002'S21.G00.40.006'MEDECIN-CHEF'
'1550756073109'S21.G00.30.001'2345678912345'
'1550756073109'S21.G00.30.002LE LIBRONX'
'1550756073109'S21.G00.30.004'Georges'
'1550756073109'S21.G00.30.006'03071955'
'1550756073109'S21.G00.30.007'GUEMENE SUR SCORFF'
'1550756073109'S21.G00.30.008'19 rue Alfred de Musset'
'1550756073109'S21.G00.30.009'22000'
'1550756073109'S21.G00.30.010'ST BRIEUC'
'1550756073109'S21.G00.30.013'01'
'1550756073109'S21.G00.30.014'56'
'1550756073109'S21.G00.30.015'FR'
'1550756073109'S21.G00.30.019'92001156'
'1550756073109'S21.G00.40.001'01012004'
'1550756073109'S21.G00.40.002'04'
'1550756073109'S21.G00.40.003'01'
'1550756073109'S21.G00.40.004'344a'
'1550756073109'S21.G00.40.006'MED CHEF SERV DIM ET ARCH MED CENT'
'1580822278044'S21.G00.30.0013456789123456'
'1580822278044'S21.G00.30.002GUEGUENEC'
'1580822278044'S21.G00.30.004'François'
'1580822278044'S21.G00.30.006'10081958'
'1580822278044'S21.G00.30.007'ST BRIEUC'
'1580822278044'S21.G00.30.008'1 rue du haut coadernault'
'1580822278044'S21.G00.30.009'22110'
'1580822278044'S21.G00.30.010MARSEILLES
'1580822278044'S21.G00.30.013'01'
'1580822278044'S21.G00.30.014'22'
'1580822278044'S21.G00.30.015'FR'
'1580822278044'S21.G00.30.019'93002024'
'1580822278044'S21.G00.40.001'18101982'
'1580822278044'S21.G00.40.002'06'
'1580822278044'S21.G00.40.003'04'
'1580822278044'S21.G00.40.004'431f'
'1580822278044'S21.G00.40.006'INFIRMIER'
'1581122295013'S21.G00.30.0014567891234567''
'1581122295013'S21.G00.30.002BLANCHARDUN'
'1581122295013'S21.G00.30.004'Lucien'
'1581122295013'S21.G00.30.006'10111958'
'1581122295013'S21.G00.30.007'ST GILLES VIEUX MARCHE'
'1581122295013'S21.G00.30.008'68 Lotissement du Verger'
'1581122295013'S21.G00.30.009'22110'
'1581122295013'S21.G00.30.010MARSEILLES
'1581122295013'S21.G00.30.013'01'
'1581122295013'S21.G00.30.014'22'
'1581122295013'S21.G00.30.015'FR'
'1581122295013'S21.G00.30.019'93032608'
'1581122295013'S21.G00.40.001'01011999'
'1581122295013'S21.G00.40.002'06'
'1581122295013'S21.G00.40.003'04'
'1581122295013'S21.G00.40.004'637d'
'1581122295013'S21.G00.40.006'CHEF D'EQUIPE BATIMENTS ET ESPACES VERTS'

 

 

I'm looking to get this.

 

N°SSS21.G00.30.001S21.G00.30.002S21.G00.30.004S21.G00.30.006S21.G00.30.007S21.G00.30.008ETC
1234567891234'BOURGEATEAU'Philippe''01041955''BESANCON''21 route de Gouarec''22110'ETC
'2345678912345'LE LIBRONX''Georges''03071955''GUEMENE SUR SCORFF''19 rue Alfred de Musset''22000'ETC
3456789123456'GUEGUENEC''François''10081958''ST BRIEUC''1 rue du haut coadernault''22110'ETC
4567891234567''BLANCHARDUN''Lucien''10111958''ST GILLES VIEUX MARCHE''68 Lotissement du Verger''22110'ETC

 

 

 

However when I apply my statement (modified compared to that of smauro ) , below, I get a result list instead of the desired text.

 

Source = Excel.CurrentWorkbook(){[Name="Tableau1"]}[Content],
Deplac_col = Table.ReorderColumns(Source,{"N°SS", "Rubrique", "Valeur"}),
NSS_Vers_le_Bas = Table.FillDown(Deplac_col,{"N°SS"}),

 

TCD = Table.Group(
NSS_Vers_le_Bas,
{"N°SS"},
List.Transform(
List.Distinct(NSS_Vers_le_Bas [Rubrique]),
(t) => {
Text.From(t),
each (Table.SelectRows(_, each [Rubrique] = t)[Valeur]),
type text
})

)

 

in
TCD

 

i obtain  a wrong result, with list and not the text of each  [Valeur]

 

N°SSS10.G00.00.001S10.G00.00.002S10.G00.00.003ETC
null[Liste][Liste][Liste]ETC
'1550425056002'[Liste][Liste][Liste]ETC
'1550756073109'[Liste][Liste][Liste]ETC

 

 

 

Could one of the members of this forum or super user give me a boost on this project.

 

 

attached also the link to the excel example file.

 

 

https://www.dropbox.com/s/znl5mjj8904zb05/DSN_Transf.xlsx?dl=0

 

A big thank you in advance

 

Philippe Muniesa

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @PhilippeMuniesa 

 

try to use Table.Pivot. This you can even get using the GUI

Here the code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("pZfbTuMwEIZfxeKaRbZz9GWauiVSkrI5ICSWi4qapRLbotA80z7Ivtg6aalT1mXIrISgOPxf0xnPh3N/f/GjpZQHzPOoyz3q+fq3/dLF5UXJ2dWc0iuHXlHK9ALjjuv5QSi6F4c/e7gcAeF6YbKoi7mMKhnV48KuXthfuXlev6xfXxXmFvwjhTLqMuF5GEpwpExkGeXxIsdQwiOFM9Js250iK0Xm23bZqEcMUBggZ4wiEIzqhSwqSpmkqSzHZZ1BbTHvbTrMMV1h3jE/KzB5Uz7Bqf7hj70L931SjjvMZyIMMBRuKGNHrc+bXogQkze9cFx3iSGYScvkVMZJ/i2+ljMrKdCYwGFUnHfPYV8MBGRvDoDqyppKkiaTYpHfYQimMHO1bX6qNwxkYCGHBmctBFCMhea1zGQuSVkXpIwXxQxVZ+MjJkjTKhK9PDVq1Ukpa9/e1A4DHTpJDxUC0Ttpf6WsyKRIZB1jMKCegLzpvOdj8qCegPypnhgbfRf/6olpkF0vAAXUE5D/j158VU8A4URPpFMTKWVxS6ZJRmRFoiK+Jv0VmVcWfkhDznkQUte1dquv89BWtmaBkK7Merb1Vy5tex4EmDrNmuXmz+/t2uYrEGOKxbQmtK9s/1NASvClOQYxA031llq15HnZ7sjjdrlSzWbZvthEBWLhwxOE+OzwBGaBiQDzg8MTx+QBO4H5gZ0c/Z1ymxc+o3ywEwu1nkQ49rN8tNPYsftoJ9SnML1wHfaEIZiBS/JZUmSJtDaFMY0Rnt495yU0dNDhKIpB9c9uqX7WuY6KaW173gERpixp+7hWGwxjaCLGzpkIopyYaN5PK7nVProjWSd+iWEaLfkhSbe7tT4x/VKbXeenW6VPig2G+gUrAYhPrQRlIStBechKUB6yEpQ/sZLDfTp2u1jOTEwIgaFAVoLykJWgvOmF7wQrDMEMX39emu5fy+91ciPJJKoS/RBSld3xSZY3UdwNlSyq8v2tHv4C", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"N°SS" = _t, Rubrique = _t, Valeur = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"N°SS", type text}, {"Rubrique", type text}, {"Valeur", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Rubrique]), "Rubrique", "Valeur")
in
    #"Pivoted Column"

Here the output

Jimmy801_0-1616755857497.png

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

View solution in original post

2 REPLIES 2
Jimmy801
Community Champion
Community Champion

Hello @PhilippeMuniesa 

 

try to use Table.Pivot. This you can even get using the GUI

Here the code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("pZfbTuMwEIZfxeKaRbZz9GWauiVSkrI5ICSWi4qapRLbotA80z7Ivtg6aalT1mXIrISgOPxf0xnPh3N/f/GjpZQHzPOoyz3q+fq3/dLF5UXJ2dWc0iuHXlHK9ALjjuv5QSi6F4c/e7gcAeF6YbKoi7mMKhnV48KuXthfuXlev6xfXxXmFvwjhTLqMuF5GEpwpExkGeXxIsdQwiOFM9Js250iK0Xm23bZqEcMUBggZ4wiEIzqhSwqSpmkqSzHZZ1BbTHvbTrMMV1h3jE/KzB5Uz7Bqf7hj70L931SjjvMZyIMMBRuKGNHrc+bXogQkze9cFx3iSGYScvkVMZJ/i2+ljMrKdCYwGFUnHfPYV8MBGRvDoDqyppKkiaTYpHfYQimMHO1bX6qNwxkYCGHBmctBFCMhea1zGQuSVkXpIwXxQxVZ+MjJkjTKhK9PDVq1Ukpa9/e1A4DHTpJDxUC0Ttpf6WsyKRIZB1jMKCegLzpvOdj8qCegPypnhgbfRf/6olpkF0vAAXUE5D/j158VU8A4URPpFMTKWVxS6ZJRmRFoiK+Jv0VmVcWfkhDznkQUte1dquv89BWtmaBkK7Merb1Vy5tex4EmDrNmuXmz+/t2uYrEGOKxbQmtK9s/1NASvClOQYxA031llq15HnZ7sjjdrlSzWbZvthEBWLhwxOE+OzwBGaBiQDzg8MTx+QBO4H5gZ0c/Z1ymxc+o3ywEwu1nkQ49rN8tNPYsftoJ9SnML1wHfaEIZiBS/JZUmSJtDaFMY0Rnt495yU0dNDhKIpB9c9uqX7WuY6KaW173gERpixp+7hWGwxjaCLGzpkIopyYaN5PK7nVProjWSd+iWEaLfkhSbe7tT4x/VKbXeenW6VPig2G+gUrAYhPrQRlIStBechKUB6yEpQ/sZLDfTp2u1jOTEwIgaFAVoLykJWgvOmF7wQrDMEMX39emu5fy+91ciPJJKoS/RBSld3xSZY3UdwNlSyq8v2tHv4C", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"N°SS" = _t, Rubrique = _t, Valeur = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"N°SS", type text}, {"Rubrique", type text}, {"Valeur", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Rubrique]), "Rubrique", "Valeur")
in
    #"Pivoted Column"

Here the output

Jimmy801_0-1616755857497.png

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

Thanks a lot

 

Ph Muniesa

Helpful resources

Announcements
Microsoft Build 768x460.png

Microsoft Build is May 24-26. Have you registered yet?

Come together to explore latest innovations in code and application development—and gain insights from experts from around the world.

charticulator_carousel_with_text (1).png

Charticulator Design Challenge

Put your data visualization and design skills to the test! This exciting challenge is happening now through May 31st!

May UG Leader Call Carousel 768x460.png

What difference can a User Group make for you?

At the monthly call, connect with other leaders and find out how community makes your experience even better.

Power BI Release May 2022 768x460.png

Check it out!

Click here to read more about the May 2022 updates!