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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
VV24
Helper III
Helper III

concatenate all values for specific value over multiple rows

dear all,

 

I like to find combinations in sales where i want to find all categories that someone bought on a day for every row in the sales table.

i have a table like this:

CustomerDateVisitkeyCategory
101-01-221/01-01-22a
101-01-221/01-01-22b
201-01-222/01-01-22c
201-01-222/01-01-22a
102-01-221/02-01-22a
102-01-221/02-01-22a
202-01-222/02-01-22b
202-01-222/02-01-22a
202-01-222/02-01-22c

and per visit i wish to determine all the categorynames per visit

the dimension table looks like this:

Categorycategoryname
aa1
bb1
cc1
dd1

 

 

and the result should look like this:

CustomerDateVisitkeyCategoryResult
101-01-221/01-01-22aa1, b1
101-01-221/01-01-22ba1, b1
201-01-222/01-01-22ca1, c1
201-01-222/01-01-22aa1, c1
102-01-221/02-01-22aa1
102-01-221/02-01-22aa1
202-01-222/02-01-22ba1, b1, c1
202-01-222/02-01-22aa1, b1, c1
202-01-222/02-01-22ca1, b1, c1

there is a relationship from category to sales table between category column from 1 - *

 

 

1 ACCEPTED SOLUTION
v-shex-msft
Community Support
Community Support

HI @VV24,

You can try to use the following calculated column formula to directly lookup and concatenate dimension table values based on the current category.

Result=
VAR list =
    CALCULATETABLE (
        VALUES ( Table[Category] ),
        FILTER ( Table, [Customer] = EARLIER ( Table[Customer] ) )
    )
RETURN
    CONCATENATEX ( FILTER ( dimension, [Category] IN list ), [categoryname], "," )

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

3 REPLIES 3
v-shex-msft
Community Support
Community Support

HI @VV24,

You can try to use the following calculated column formula to directly lookup and concatenate dimension table values based on the current category.

Result=
VAR list =
    CALCULATETABLE (
        VALUES ( Table[Category] ),
        FILTER ( Table, [Customer] = EARLIER ( Table[Customer] ) )
    )
RETURN
    CONCATENATEX ( FILTER ( dimension, [Category] IN list ), [categoryname], "," )

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
VV24
Helper III
Helper III

thanks, its working! and lets say if you have a *-* relationship between those two tables, is there a way to solve it then?

 

rohit_singh
Solution Sage
Solution Sage

Hi @VV24 ,

Please try the steps given below :

1) Create a 1:M relationship between the dim and fact tables on the category field.

 

rohit_singh_0-1652968924159.png

2) Using the relationship defined above, create a new calculated column on the fact table.

 

Cat name = RELATED(dim_categoryname[categoryname])

 

rohit_singh_1-1652969330297.png

 

3) Finally, create another calculated column using the column created above that will give you the desired result.

 

rohit_singh_2-1652969350106.png

 

Daily Categories =
CALCULATE(
CONCATENATEX(VALUES(fact_categorynames[Cat name]), fact_categorynames[Cat name], " , "),
ALLEXCEPT(fact_categorynames,fact_categorynames[Date],fact_categorynames[Customer])
)


Kind regards,

Rohit


Please mark this answer as the solution if it resolves your issue.
Appreciate your kudos! 😊

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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