Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Shape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.

Reply
Anonymous
Not applicable

Combine all possible values from a single column- Power query

 

Raw Data

simesman_0-1657279205816.png

 

How can I get all the possible combination of 7 companies with unique ID?

-Count 1-7

-All Combination of company, e.g. count=1, only show A/B/C/D/E/F/G price in one row

-Sum of the combined companies price

 

 

1 ACCEPTED SOLUTION

@Anonymous Using my code I referenced previously, I turned it into a function fn_Subsets that transforms a list into a list of subsets (a list of lists).

(L as list) as list =>
let
  N = List.Count(L),
  Subsets =
      List.Transform(
          {0..Number.Power(2, N)-1},
          (i) => List.Transform(
                     {0..N-1},
                     (j) => if Number.Mod(Number.IntegerDivide(i, Number.Power(2, j)), 2) = 1
                            then L{j}
                            else null
                 )
      ),
  RemoveNulls = List.Transform(Subsets, each List.RemoveNulls(_))
in
  RemoveNulls

 

We can apply this function in a Group By set to each set of companies associated with each ID.

 

Here's a complete sample query (including the function definition) you can paste into the Advanced Editor of a new blank query.

let
    /*Define a list function. This is usually done in a separate query.*/
    fn_Subsets = (L as list) as list =>
    let
        N = List.Count(L),
        Subsets =
            List.Transform(
                {0..Number.Power(2, N)-1},
                (i) => List.Transform(
                            {0..N-1},
                            (j) => if Number.Mod(Number.IntegerDivide(i, Number.Power(2, j)), 2) = 1
                                    then L{j}
                                    else null
                        )
            ),
        RemoveNulls = List.Transform(Subsets, each List.RemoveNulls(_))
    in
        RemoveNulls,

    /*Define sample dataset. Replace with your own data.*/
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Rcy7DcAgFEPRXVxTBPIvSQjkMwJ6+68RIyG5uJJP41oRPRwi8zDXebAgnmwVE9vEi+1ibleDXJr7d+C+2Sg+bBJfNosfW2D2Aw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Company = _t, Price = _t]),
    SampleData = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Company", type text}, {"Price", Int64.Type}}),
    
    /*Logic applying the subsets function and aggregating the results.*/
    #"Grouped Rows" = Table.Group(SampleData, {"ID"}, {{"SubsetList", each fn_Subsets([Company]), type list}}),
    #"Expanded Count" = Table.ExpandListColumn(#"Grouped Rows", "SubsetList"),
    #"Added Custom" = Table.AddColumn(#"Expanded Count", "Company", each Text.Combine([SubsetList], ","), type text),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Company] <> "")),
    #"Expanded SubsetList" = Table.ExpandListColumn(#"Filtered Rows", "SubsetList"),
    #"Merged Queries" = Table.NestedJoin(#"Expanded SubsetList", {"ID", "SubsetList"}, SampleData, {"ID", "Company"}, "Expanded SubsetList", JoinKind.LeftOuter),
    #"Expanded Expanded SubsetList" = Table.ExpandTableColumn(#"Merged Queries", "Expanded SubsetList", {"Price"}, {"Price"}),
    #"Aggregate Rows" = Table.Group(#"Expanded Expanded SubsetList", {"ID", "Company"}, {{"Sum_Price", each List.Sum([Price]), type nullable number}, {"No of Supplier", each Table.RowCount(_), Int64.Type}}),
    #"Sorted Rows" = Table.Sort(#"Aggregate Rows",{{"ID", Order.Ascending}, {"No of Supplier", Order.Ascending}, {"Company", Order.Ascending}})
in
    #"Sorted Rows"

 

View solution in original post

12 REPLIES 12
pfarias
Advocate I
Advocate I

  1. First, you must group the table by ID and return all rows and perform the sum of the price.

pfarias_0-1657326422014.png

pfarias_1-1657326520497.png

 

2. After, add a new custom column and use the function Combiner.CombineTextByDelimiter. Use the delimiter "/" and combine the collumn from grouped table COMPANY;

 

= Combiner.CombineTextByDelimiter("/")([TABLE_GROUP][COMPANY])

 

pfarias_2-1657326633566.png

 

pfarias_3-1657326666986.png

 

Finally, only select the columns

pfarias_4-1657326740653.png

 

 

 

Sample M

 

let
    Fonte = Excel.CurrentWorkbook(){[Name="sAMPLE"]}[Content],
    GroupID = Table.Group(Fonte, {"ID"}, {{"TABLE_GROUP", each _, type table [ID=nullable text, COMPANY=nullable text, PRICE=nullable number]}, {"SUM_PRICE", each List.Sum([PRICE]), type nullable number}}),
    CombineCompany = Table.AddColumn(GroupID, "COMPANY", each Combiner.CombineTextByDelimiter("/")([TABLE_GROUP][COMPANY]), type text),
    SelectColumns = Table.SelectColumns(CombineCompany,{"ID", "COMPANY", "SUM_PRICE"})
in
    SelectColumns

 

 

 

Anonymous
Not applicable

Thank you for your comment. But I would like to know how many possible combination and its sum of price for 1to 7 suppliers.

e.g

simesman_0-1657375974614.png

 

Hi @Anonymous ,

 

With the brilliant code provided by @AlexisOlson, I applied it to your case. This is not achievable without Alexis' code. Very smart!!

Please see below outcome:

KT_Bsmart2gethe_0-1657621572214.png

 

Open a blank query and paste over the code below (delete out the existing code first).

 

Code:

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcjRU0lFyBGJjY6VYHSjfCYiNjBB8ZyA2gcobwdSbIPhg9UjyIPWGQP2xAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Company = _t, Price = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Company", type text}, {"Price", Int64.Type}}),

//Group rows to do the count of companies
#"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"Count", each Table.RowCount(_), Int64.Type}}),

//Combination transformation - Company
Subset = Table.AddColumn(#"Grouped Rows", "Subset", each List.Transform(
{0..Number.Power(2, [Count])-1},
(i) => List.Transform(
{0..[Count]-1},
(j) => if Number.Mod(Number.IntegerDivide(i, Number.Power(2, j)), 2) = 1
then Table.SelectRows(#"Changed Type", (x)=>x[ID]=[ID])[Company]{j}
else null
)
)),
Concatenate = Table.AddColumn(Subset, "Concatenate", each List.Transform([Subset], each Text.Combine(List.RemoveNulls(_), ","))),

//Combination transformation - Price
#"Subset$" = Table.AddColumn(Concatenate, "Subset $", each List.Transform(
{0..Number.Power(2, [Count])-1},
(i) => List.Transform(
{0..[Count]-1},
(j) => if Number.Mod(Number.IntegerDivide(i, Number.Power(2, j)), 2) = 1
then Table.SelectRows(#"Changed Type", (x)=>x[ID]=[ID])[Price]{j}
else null
)
)),
#"Concatenate$" = Table.AddColumn(#"Subset$", "Concatenate$", each List.Transform([#"Subset $"], each List.Sum(List.RemoveNulls(_)))),

//Join list (Company & Price)
#"Added Custom" = Table.AddColumn(#"Concatenate$", "Company", each List.Zip({[Concatenate],[#"Concatenate$"]})),

//Expand join list
#"Expanded Combine" = Table.ExpandListColumn(#"Added Custom", "Company"),

//Expand join sub-list
#"Expanded Combine1" = Table.ExpandListColumn(#"Expanded Combine", "Company"),
#"Added Index" = Table.AddIndexColumn(#"Expanded Combine1", "Index", 0, 1, Int64.Type),
#"Added Custom1" = Table.AddColumn(#"Added Index", "Price", each #"Added Index"[Company]{[Index]+1}),

//Aligning Company and Price
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "Filter", each try Value.Is([Price], type number) otherwise false),

//Filter out unnecessary rows
#"Filtered Rows1" = Table.SelectRows(#"Added Custom2", each ([Filter] = true)),

//Remove unnecessary columns
#"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows1",{"ID", "Company", "Price" }),

//number of supplier
#"Added Custom3" = Table.AddColumn(#"Removed Other Columns", "No of Supplier", each List.Count(Text.Split([Company],",")))
in
#"Added Custom3"

 

Regards

KT

 

KT_Bsmart2gethe
Impactful Individual
Impactful Individual

Hi @Anonymous ,

 

Please see code below (highlighted code show is the code to get the combination):

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcjRU0lFyBGJjY6VYHSjfCYiNjBB8ZyA2gcobwdSbIPhg9UjyIPWGQP2xAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Company = _t, Price = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Company", type text}, {"Price", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Count", each Table.SelectRows(#"Changed Type", (x)=>x[Company]=[Company])[ID]),
#"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Count", each Text.Combine(List.Transform(_, Text.From), ";"), type text})
in
#"Extracted Values"

 

KT_Bsmart2gethe_1-1657321737008.png

 

Regards

KT

 

Anonymous
Not applicable

Thank you for your comment. But I would like to know how many possible combination and its sum of price for 1to 7 suppliers within the same ID

e.g

simesman_1-1657376004494.png

 

 

You might be interested in my comment here. It has all the basic math needed.

 

Note that there are 2^7 = 128 combinations for 7 companies. The size can get out of hand really quickly if you try to precompute all possibilities. I'm not sure what your ultimate goal is, but it might be better not to try to precompute everything but rather calculate combinations with DAX measures.

@Anonymous Using my code I referenced previously, I turned it into a function fn_Subsets that transforms a list into a list of subsets (a list of lists).

(L as list) as list =>
let
  N = List.Count(L),
  Subsets =
      List.Transform(
          {0..Number.Power(2, N)-1},
          (i) => List.Transform(
                     {0..N-1},
                     (j) => if Number.Mod(Number.IntegerDivide(i, Number.Power(2, j)), 2) = 1
                            then L{j}
                            else null
                 )
      ),
  RemoveNulls = List.Transform(Subsets, each List.RemoveNulls(_))
in
  RemoveNulls

 

We can apply this function in a Group By set to each set of companies associated with each ID.

 

Here's a complete sample query (including the function definition) you can paste into the Advanced Editor of a new blank query.

let
    /*Define a list function. This is usually done in a separate query.*/
    fn_Subsets = (L as list) as list =>
    let
        N = List.Count(L),
        Subsets =
            List.Transform(
                {0..Number.Power(2, N)-1},
                (i) => List.Transform(
                            {0..N-1},
                            (j) => if Number.Mod(Number.IntegerDivide(i, Number.Power(2, j)), 2) = 1
                                    then L{j}
                                    else null
                        )
            ),
        RemoveNulls = List.Transform(Subsets, each List.RemoveNulls(_))
    in
        RemoveNulls,

    /*Define sample dataset. Replace with your own data.*/
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Rcy7DcAgFEPRXVxTBPIvSQjkMwJ6+68RIyG5uJJP41oRPRwi8zDXebAgnmwVE9vEi+1ibleDXJr7d+C+2Sg+bBJfNosfW2D2Aw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Company = _t, Price = _t]),
    SampleData = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Company", type text}, {"Price", Int64.Type}}),
    
    /*Logic applying the subsets function and aggregating the results.*/
    #"Grouped Rows" = Table.Group(SampleData, {"ID"}, {{"SubsetList", each fn_Subsets([Company]), type list}}),
    #"Expanded Count" = Table.ExpandListColumn(#"Grouped Rows", "SubsetList"),
    #"Added Custom" = Table.AddColumn(#"Expanded Count", "Company", each Text.Combine([SubsetList], ","), type text),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Company] <> "")),
    #"Expanded SubsetList" = Table.ExpandListColumn(#"Filtered Rows", "SubsetList"),
    #"Merged Queries" = Table.NestedJoin(#"Expanded SubsetList", {"ID", "SubsetList"}, SampleData, {"ID", "Company"}, "Expanded SubsetList", JoinKind.LeftOuter),
    #"Expanded Expanded SubsetList" = Table.ExpandTableColumn(#"Merged Queries", "Expanded SubsetList", {"Price"}, {"Price"}),
    #"Aggregate Rows" = Table.Group(#"Expanded Expanded SubsetList", {"ID", "Company"}, {{"Sum_Price", each List.Sum([Price]), type nullable number}, {"No of Supplier", each Table.RowCount(_), Int64.Type}}),
    #"Sorted Rows" = Table.Sort(#"Aggregate Rows",{{"ID", Order.Ascending}, {"No of Supplier", Order.Ascending}, {"Company", Order.Ascending}})
in
    #"Sorted Rows"

 

Anonymous
Not applicable

Raw Data 

simesman_0-1657375731859.png

Result Example

simesman_1-1657375746554.png

How to get the 7! (factorial) number of all possible combination on company col for the unique ID?

I would like to have 1 to 7  of suppliers and see the all the possible combinations.

 

 

 

7! is the number of permutations of seven companies, not the number of possible combinations.

 

See my answer to your previous question here:
https://community.powerbi.com/t5/Power-Query/Combine-all-possible-values-from-a-single-column-Power-...

Anonymous
Not applicable

Hi @miguel ,

 

As I havent got the corrected answer , I had created one new question for more elaboration!

Hi @Anonymous ,

 

I'll have a think through about what can be done. It is easy to find out how many combinations but to list them out in a way like A; A B; A C ....... It is quite a challenge, but I will have a go.

 

Regards

KT 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.