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
Anonymous
Not applicable

I have a table 'Leads'. It has a has-many-through relationship with table labels

I have a table leads

IDnameemail
123john doejohndoe@xyz.com

 

It has a has-many-through association with labels table.

IDname
456test

The association is through labelings table.

IDlead_idlabel_id
1123456

 

Now when I try to create a table visual, a lead having more than 1 labels is shown in different rows.

Screenshot (4).png

 

What should i do so that a lead with more than 1 label only has 1 row with associated labels as an array or just comma separated ?

1 ACCEPTED SOLUTION

Hello @Anonymous 

 

if you don't want to have this as measure, then add a new column to your leads-table with exactly the same code as I wrote in my post

 

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

6 REPLIES 6
v-alq-msft
Community Support
Community Support

Hi, @Anonymous 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Labels:

a1.png

Leads:

a2.png

Association:

a3.png

 

You may create a measure or a column as below.

Measure:

Measure = 
CONCATENATEX(
    FILTER(
        Labels,
        [ID]=MAX(Association[Label_id])
    ),
    [Name],
    ","
)

Column:

Column = 
CONCATENATEX(
    FILTER(
        Labels,
        [ID]=EARLIER(Association[Label_id])
    ),
    [Name],
    ","
)

 

a4.png

 

Or you can create a calculated table with the following dax.

Table = 
ADDCOLUMNS(
    DISTINCT(Association[Lead_id]),
    "Label Names",
    var lid = LOOKUPVALUE(Association[Label_id],Association[Lead_id],[Lead_id])
    return
    CONCATENATEX(
        FILTER(
            Labels,
            [ID]=lid
        ),
        [Name],
        ","
    )
)

 

Result:

a5.png

 

Best Regards

Allan

 

If this post helps,then consider Accepting it as the solution to help other members find it faster.

 

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

you can transform you data with power query. First Join to the association-table, then the lable.table. Afterwards use Table.Group to combine your labels.text to one string. Here the code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyVtJRysrPyFNIyU+FMoEsh4rKKr3k/Fyl2FgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, name = _t, email = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"name", type text}, {"email", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"ID"}, association, {"lead_id"}, "association", JoinKind.LeftOuter),
    #"Expanded association" = Table.ExpandTableColumn(#"Merged Queries", "association", {"label_id"}, {"label_id"}),
    #"Merged Queries1" = Table.NestedJoin(#"Expanded association", {"label_id"}, lable, {"ID"}, "lable", JoinKind.LeftOuter),
    #"Expanded lable" = Table.ExpandTableColumn(#"Merged Queries1", "lable", {"name"}, {"name.1"}),
    #"Grouped Rows" = Table.Group(#"Expanded lable", {"ID", "name", "email"}, {{"Lable names", each Text.Combine(_[#"name.1"], ", "), type text}})
in
    #"Grouped Rows"

Jimmy801_0-1605682686534.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

You can use also a measure or a new column to do that in Dax

LabelNames = CALCULATE(CONCATENATEX(lable,lable[name], ", "),filter(values(lable[ID]),COUNTROWS(RELATEDTABLE(association))>0))


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

 

Anonymous
Not applicable

I implemented the DAX query, but it didn't work. All the labels got accumulated in the total row.

Hello @Anonymous 

 

if you don't want to have this as measure, then add a new column to your leads-table with exactly the same code as I wrote in my post

 

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

 

 

lbendlin
Super User
Super User

Show your data model. "Leads" and "Labels"  should be the "dimension"  tables and "Associations" the "fact" table.

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.

Top Solution Authors
Top Kudoed Authors