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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
Asking
Regular Visitor

Comma Separated List

Hi,

 

I have 1 table with the first column as ID:

1 X Y

1 X1 Y

2 X Z

2 X1 Z

3 X2 Z

1 X4 F

 

After this table is filterd by a slicer on the report, Let's say Y and Z from 3rd column are chosen, I want to create a count of all the possible combinations from the second column. In this case:

Combination Count

X,X1               2 (there are 2 ID's with X,X1)

X2                  1 (there is 1 ID with X2)

 

Is that possible please?

 

1 ACCEPTED SOLUTION
tamerj1
Super User
Super User

Hi @Asking 
This not as simple as it sounds. The reason is that there is no column to slice by. Long story short, please refer to attched file and following screenshots. You have to have either index or Date column. If don't, then use power query to add an index column. Please let me know if you need any further help.

1.png4.png2.png3.png

Combination = 
VAR T1 =
    SUMMARIZE (
        'Table',
        'Table'[Column1],
        "@Index", MAX ( 'Table'[Index] ),
        "@Combination", CONCATENATEX ( 'Table', 'Table'[Column2], "," )
    )
VAR T2 =
    SUMMARIZE ( 
        T1, 
        [@Combination],
        "@@Index", MAX ( 'Table'[Index] )
    )
VAR T3 =
    ADDCOLUMNS ( 
        T2,
        "@Rank", RANKX ( T2, [@@Index],, ASC, Dense ) 
    )
RETURN
    MAXX ( 
        FILTER ( T3, [@Rank] = SELECTEDVALUE ( 'Table 2'[Value] ) ),
        [@Combination]
    )
Count = 
VAR T1 =
    SUMMARIZE (
        'Table',
        'Table'[Column1],
        "@Index", MAX ( 'Table'[Index] ),
        "@Combination", CONCATENATEX ( 'Table', 'Table'[Column2], "," )
    )
VAR T2 =
    SUMMARIZE ( 
        T1, 
        [@Combination],
        "@@Index", MAX ( 'Table'[Index] ),
        "@Count", COUNTROWS ( FILTER ( T1, [@Combination] = EARLIER ( [@Combination] ) ) )
    )
VAR T3 =
    ADDCOLUMNS ( 
        T2,
        "@Rank", RANKX ( T2, [@@Index],, ASC, Dense ) 
    )
RETURN
    MAXX ( 
        FILTER ( T3, [@Rank] = SELECTEDVALUE ( 'Table 2'[Value] ) ),
        [@Count]
    )

View solution in original post

5 REPLIES 5
tamerj1
Super User
Super User

Hi @Asking 
This not as simple as it sounds. The reason is that there is no column to slice by. Long story short, please refer to attched file and following screenshots. You have to have either index or Date column. If don't, then use power query to add an index column. Please let me know if you need any further help.

1.png4.png2.png3.png

Combination = 
VAR T1 =
    SUMMARIZE (
        'Table',
        'Table'[Column1],
        "@Index", MAX ( 'Table'[Index] ),
        "@Combination", CONCATENATEX ( 'Table', 'Table'[Column2], "," )
    )
VAR T2 =
    SUMMARIZE ( 
        T1, 
        [@Combination],
        "@@Index", MAX ( 'Table'[Index] )
    )
VAR T3 =
    ADDCOLUMNS ( 
        T2,
        "@Rank", RANKX ( T2, [@@Index],, ASC, Dense ) 
    )
RETURN
    MAXX ( 
        FILTER ( T3, [@Rank] = SELECTEDVALUE ( 'Table 2'[Value] ) ),
        [@Combination]
    )
Count = 
VAR T1 =
    SUMMARIZE (
        'Table',
        'Table'[Column1],
        "@Index", MAX ( 'Table'[Index] ),
        "@Combination", CONCATENATEX ( 'Table', 'Table'[Column2], "," )
    )
VAR T2 =
    SUMMARIZE ( 
        T1, 
        [@Combination],
        "@@Index", MAX ( 'Table'[Index] ),
        "@Count", COUNTROWS ( FILTER ( T1, [@Combination] = EARLIER ( [@Combination] ) ) )
    )
VAR T3 =
    ADDCOLUMNS ( 
        T2,
        "@Rank", RANKX ( T2, [@@Index],, ASC, Dense ) 
    )
RETURN
    MAXX ( 
        FILTER ( T3, [@Rank] = SELECTEDVALUE ( 'Table 2'[Value] ) ),
        [@Count]
    )

Thank you. That helped.

Is there a way I can show the result as a stacked bar chart. I would like the "combination" to be in the Y axis and the "count" in the X but I understand I can't put a measure in the Y...

Hi @Asking 
I hope this is what you're looking for. Please refer to attached updated sample file.

1.png2.png

Combinations = 
SELECTCOLUMNS (
    SUMMARIZE (
        'Table',
        'Table'[Column1],
        "@Combination", CONCATENATEX ( 'Table', 'Table'[Column2], "," )
    ),
    "Combination", 
    [@Combination]
)
Count2 = 
VAR T1 =
    SUMMARIZE (
        'Table',
        'Table'[Column1],
        "@Combination", CONCATENATEX ( 'Table', 'Table'[Column2], "," )
    )
VAR T2 =
    SUMMARIZE ( 
        T1, 
        [@Combination],
        "@Count", COUNTROWS ( FILTER ( T1, [@Combination] = EARLIER ( [@Combination] ) ) )
    )
RETURN
    MAXX ( 
        FILTER ( T2, [@Combination] = SELECTEDVALUE ( Combinations[Combination] ) ),
        [@Count]
    )
Asking
Regular Visitor

Thank you.

However, how do I create the actual table and not only get the scalar value please?

Greg_Deckler
Community Champion
Community Champion

@Asking Try this:

Measure = 
    VAR __Table = ADDCOLUMNS(SUMMARIZE('Table',[Column3]),"__Text",CONCATENATEX('Table',[Column2],","))
    VAR __Values = DISTINCT(SELECTCOLUMNS(__Table,"__Text",[__Text]))
    VAR __Table1 = ADDCOLUMNS(SUMMARIZE('Table',[Column1]),"__Text",CONCATENATEX('Table',[Column2],","))
    VAR __Table2 = FILTER(__Table1,[__Text] IN __Values)
    VAR __Result = COUNTROWS(DISTINCT(SELECTCOLUMNS(__Table2,"__Index",[Column1])))
RETURN
    __Result


Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.