cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
vpatel55
Kudo Collector
Kudo Collector

Creating a new table with a cartesian product column

Hello,

 

I am trying to create a new table containing every combination of Product in within one transaction id. So if transaction 1 contained 3 different products, that would be 3 x 3 = 9 combinations. This needs to be done in DAX.

 

The input is this:

 

Transaction IdCustomerProduct
1John SmithGrapefruit
1John SmithOrange
1John SmithPineapple
2Lucy JonesMelon
2Lucy JonesJackfruit
3Amy SycamoreGrapefruit
4Daniel JohnsonOrange
5Jimmy JohnsonPineapple

 

The expected output is this, where Product 1 and Product 2 show every combination of product in that Transaction id.

 

Transaction IdCustomerProduct 1Product 2
1John SmithGrapefruitGrapefruit
1John SmithGrapefruitOrange
1John SmithGrapefruitPineapple
1John SmithOrangeGrapefruit
1John SmithOrangeOrange
1John SmithOrangePineapple
1John SmithPineappleGrapefruit
1John SmithPineappleOrange
1John SmithPineapplePineapple
2Lucy JonesMelonMelon
2Lucy JonesJackfruitMelon
2Lucy JonesMelonJackfruit
2Lucy JonesJackfruitJackfruit
3Amy SycamoreGrapefruitGrapefruit
4Daniel JohnsonOrangeOrange
5Jimmy JohnsonPineapplePineapple

 

A link to the input file is here:

 

https://www.dropbox.com/s/m4uffww780eoi71/Sample%20file.pbix?dl=0

 

A kudos for anyone with a solution. Thanks in advance.

1 ACCEPTED SOLUTION
DataInsights
Super User
Super User

@vpatel55,

 

Try this calculated table. The SELECTCOLUMNS function is necessary in order to rename the Product column, since CROSSJOIN doesn't allow two columns with the same name.

 

Cross Join = 
GENERATE (
    SUMMARIZE ( Data, Data[Transaction Id], Data[Customer] ),
    VAR vTransId = Data[Transaction Id]
    VAR vProduct1 =
        CALCULATETABLE ( VALUES ( Data[Product] ), Data[Transaction Id] = vTransId )
    VAR vProduct2 =
        SELECTCOLUMNS (
            CALCULATETABLE ( VALUES ( Data[Product] ), Data[Transaction Id] = vTransId ),
            "Product2", Data[Product]
        )
    RETURN
        CROSSJOIN ( vProduct1, vProduct2 )
)

 

DataInsights_0-1623278993964.png

 

View solution in original post

2 REPLIES 2
vpatel55
Kudo Collector
Kudo Collector

@DataInsights , that works perfectly! I didn't think to use GENERATE. This had me stumped, so huge kudos for helping with this.

DataInsights
Super User
Super User

@vpatel55,

 

Try this calculated table. The SELECTCOLUMNS function is necessary in order to rename the Product column, since CROSSJOIN doesn't allow two columns with the same name.

 

Cross Join = 
GENERATE (
    SUMMARIZE ( Data, Data[Transaction Id], Data[Customer] ),
    VAR vTransId = Data[Transaction Id]
    VAR vProduct1 =
        CALCULATETABLE ( VALUES ( Data[Product] ), Data[Transaction Id] = vTransId )
    VAR vProduct2 =
        SELECTCOLUMNS (
            CALCULATETABLE ( VALUES ( Data[Product] ), Data[Transaction Id] = vTransId ),
            "Product2", Data[Product]
        )
    RETURN
        CROSSJOIN ( vProduct1, vProduct2 )
)

 

DataInsights_0-1623278993964.png

 

View solution in original post

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!

User Group Leader Meeting January 768x460.png

Calling all User Group Leaders!

Don't miss the User Group Leader meetings on January, 24th & 25th, 2022.

Jan 2022 Dev Camp 768x460 copy.png

Power BI Dev Camp- January 27th, 2022

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors