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
charleshale
Responsive Resident
Responsive Resident

Resources for basic Dax Group By Concatenating Values

Does anyone have any resources or guides for how to achieve the equivalent to M Query's Group By in DAX with turning a secondary column into a list of values?   I'm not seeing how to do that in guides like https://dax.guide/groupby/

 

The use case is a table that might look like this

EmailAccessed From
foo@bar.comSeattle, WA
foo@bar.comLos Angeles, CA
foo@bar.comSan Diego, CA
love@powerbi.comBoston, MA

 

The idea would be to SUMMARIZE () the table so that the summary is grouped by Email:

EmailAccessed From
foo@bar.comSeattle, WA|Los Angeles, CA|San Diego, CA
love@powerbi.comBoston, MA

 

Any suggestions?   I'd think it's groupby then a concatenatex of some form?

 

Thank you

3 ACCEPTED SOLUTIONS
vicky_
Super User
Super User

you can try something like:

Table = ADDCOLUMNS(VALUES([email]), "Accessed From", CONCATENATEX(Table, [Accessed From], "|"))

View solution in original post

danextian
Super User
Super User

As a calculated table:

Table2 =
SUMMARIZE (
    'Table',
    'Table'[Email],
    "Accessed From",
        CONCATENATEX (
            VALUES ( 'Table'[Accessed From] ),
            'Table'[Accessed From],
            " | "
        )
)









Did I answer your question? Mark my post as a solution!


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

View solution in original post

charleshale
Responsive Resident
Responsive Resident

Update - this code fixed the problem

 

a_usacities_sum =
ADDCOLUMNS(
    DISTINCT(
        SUMMARIZE(a_uscities, a_uscities[city], a_uscities[Count Dupes])),
    "States",
    VAR _city = a_uscities[city]
    RETURN
    CALCULATE(
        CONCATENATEX(VALUES ( 'a_uscities'[state_id] ),
            'a_uscities'[state_id],
            " | "),
            a_uscities[city] = _city)
)

View solution in original post

4 REPLIES 4
charleshale
Responsive Resident
Responsive Resident

Update - this code fixed the problem

 

a_usacities_sum =
ADDCOLUMNS(
    DISTINCT(
        SUMMARIZE(a_uscities, a_uscities[city], a_uscities[Count Dupes])),
    "States",
    VAR _city = a_uscities[city]
    RETURN
    CALCULATE(
        CONCATENATEX(VALUES ( 'a_uscities'[state_id] ),
            'a_uscities'[state_id],
            " | "),
            a_uscities[city] = _city)
)
charleshale
Responsive Resident
Responsive Resident

Uh oh.  I am actually losing row context trying this with a geo table where I am trying to take the 107,000 incorporated towns in the US and concatenatex the names of the states where there are dupes

 

a_usacities_sum = 
ADDCOLUMNS(
    DISTINCT(SUMMARIZE(a_uscities,
    a_uscities[city], a_uscities[Count Dupes])),
    "States", CONCATENATEX(VALUES ( 'a_uscities'[state_id] ),
            'a_uscities'[state_id],
            " | "
))

The above is missing row context 

charleshale_0-1692977621974.png

 

Going to try some some filter code changes

 

danextian
Super User
Super User

As a calculated table:

Table2 =
SUMMARIZE (
    'Table',
    'Table'[Email],
    "Accessed From",
        CONCATENATEX (
            VALUES ( 'Table'[Accessed From] ),
            'Table'[Accessed From],
            " | "
        )
)









Did I answer your question? Mark my post as a solution!


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.
vicky_
Super User
Super User

you can try something like:

Table = ADDCOLUMNS(VALUES([email]), "Accessed From", CONCATENATEX(Table, [Accessed From], "|"))

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.