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
iplaygod
Resolver I
Resolver I

DAX: CALCULATETABLE how restrict rows found to max 1 per User ID

Hi all

I have a sales table. Each row in the sales table has the field [User ID] indicating who made that purchase.
So there are multiple rows for each User ID. The number of sales rows per User ID depends on their purchase history.

I am trying to write a calculatetable that will give me only max 1 sales row per unique User ID found in the sales table.
I want the first row that matches the filter I am applying, for each unique User ID.

The problem with my current code is that it is retrieving several sales rows for some users (who happen to have several rows matching my filter)

The current filter context will filter the sales table by a date range etc.
I then add to that filter context.
What I have now is:

VAR filteredRowsTable = 
    CALCULATETABLE(sales;
        FILTER(sales;
            sales[flag one] = 1
            && sales[flag two] = 1
            && RELATED(products[Product Line]) = "Shoes"
        )
    )

How can I change the code to accomplish my goal?

Basically, the pseudo code is:
Apply the filter to the sales table
Now extract distinct User IDs from that filtered table
Now give me only the first found sales row, from the filtered rows in the sales table, for each of those distinct User IDs

Please give me some code example.
Thanks!

thanks

1 ACCEPTED SOLUTION

@iplaygod

 

Another way could be to use TOPN function

=
VAR TOPROWS =
    GENERATE (
        VALUES ( Sales[User ID] ),
        VAR mytable =
            CALCULATETABLE ( TOPN ( 1, Sales, [SalesColumn], DESC ) )
        RETURN
            SUMMARIZE ( mytable, [SalesColumn] )
    )
VAR filteredRowsTable =
    CALCULATETABLE (
        sales,
        TOPROWS,
        FILTER (
            sales,
            sales[flag one] = 1
                && sales[flag two] = 1
                && RELATED ( products[Product Line] ) = "Shoes"
        )
    )
RETURN
    filteredRowsTable

 

 


Regards
Zubair

Please try my custom visuals

View solution in original post

3 REPLIES 3
Zubair_Muhammad
Community Champion
Community Champion

@iplaygod

 

Try this

 

VAR filteredRowsTable =
    CALCULATETABLE (
        sales,
        FILTER (
            sales,
            sales[flag one] = 1
                && sales[flag two] = 1
                && RELATED ( products[Product Line] ) = "Shoes"
        )
    )
VAR RankRowsforeachID =
    ADDCOLUMNS (
        filteredRowsTable,
        "RANK", RANKX (
            FILTER ( filteredRowsTable, [User ID] = EARLIER ( [User ID] ) ),
            [Sales],
            ,
            DESC,
            DENSE
        )
    )
VAR TablewithMaxRows=
    FILTER ( RankRowsforeachID, [RANK] = 1 )

 

 


Regards
Zubair

Please try my custom visuals

@iplaygod

 

Another way could be to use TOPN function

=
VAR TOPROWS =
    GENERATE (
        VALUES ( Sales[User ID] ),
        VAR mytable =
            CALCULATETABLE ( TOPN ( 1, Sales, [SalesColumn], DESC ) )
        RETURN
            SUMMARIZE ( mytable, [SalesColumn] )
    )
VAR filteredRowsTable =
    CALCULATETABLE (
        sales,
        TOPROWS,
        FILTER (
            sales,
            sales[flag one] = 1
                && sales[flag two] = 1
                && RELATED ( products[Product Line] ) = "Shoes"
        )
    )
RETURN
    filteredRowsTable

 

 


Regards
Zubair

Please try my custom visuals

thanks for the suggestions!

 

i will try and get back

 

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.