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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
rbowen
Helper III
Helper III

Create New Calculated Table From Existing Table With Only Maximum Value For Each Customer

I have an existing table in my BI Desktop report that has multiple customer accounts and the various store locations they've made purchases from. Here's an example of what it looks like for just two of the customer accounts:

 

rbowen_0-1710856324478.png

 

What I'm trying to do is create a new table where the results only contain what store each customer has the most transactions with. So, in the example above, the new table would contain only one result per customer account and would like like this:

 

rbowen_1-1710856619490.png

 

I've tried using various DAX functions to get this done but having no luck. At best, I can get multiple rows per customer showing a summed result for each store they've done transactions with, but not limited to only the store they've used the most. Any guidance would be appreciated.

 

Thank you.

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @rbowen 

Yo can refer to the following code.

Create a calculated table.

Table 2 =
VAR a =
    SUMMARIZE (
        'Table',
        [Customer Number],
        [Customer Name],
        "Max Tra", MAX ( 'Table'[Transaction Counter] )
    )
RETURN
    ADDCOLUMNS (
        a,
        "Max Store Number",
            MAXX (
                FILTER (
                    'Table',
                    [Customer Number] = EARLIER ( 'Table'[Customer Number] )
                        && [Customer Name] = EARLIER ( 'Table'[Customer Name] )
                        && [Transaction Counter] = EARLIER ( [Max Tra] )
                ),
                [Store Number]
            ),
        "Max Store Name",
            MAXX (
                FILTER (
                    'Table',
                    [Customer Number] = EARLIER ( 'Table'[Customer Number] )
                        && [Customer Name] = EARLIER ( 'Table'[Customer Name] )
                        && [Transaction Counter] = EARLIER ( [Max Tra] )
                ),
                [Store Name]
            )
    )

Output

vxinruzhumsft_0-1710902775633.png

 

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
Ashish_Mathur
Super User
Super User

Hi,

Would you be OK with a Power Query solution?  If yes, then share data in a format that can be pasted in an MS Excel file.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Anonymous
Not applicable

Hi @rbowen 

Yo can refer to the following code.

Create a calculated table.

Table 2 =
VAR a =
    SUMMARIZE (
        'Table',
        [Customer Number],
        [Customer Name],
        "Max Tra", MAX ( 'Table'[Transaction Counter] )
    )
RETURN
    ADDCOLUMNS (
        a,
        "Max Store Number",
            MAXX (
                FILTER (
                    'Table',
                    [Customer Number] = EARLIER ( 'Table'[Customer Number] )
                        && [Customer Name] = EARLIER ( 'Table'[Customer Name] )
                        && [Transaction Counter] = EARLIER ( [Max Tra] )
                ),
                [Store Number]
            ),
        "Max Store Name",
            MAXX (
                FILTER (
                    'Table',
                    [Customer Number] = EARLIER ( 'Table'[Customer Number] )
                        && [Customer Name] = EARLIER ( 'Table'[Customer Name] )
                        && [Transaction Counter] = EARLIER ( [Max Tra] )
                ),
                [Store Name]
            )
    )

Output

vxinruzhumsft_0-1710902775633.png

 

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you Zhu, that worked perfectly!

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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.