Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
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
Solved! Go to Solution.
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
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 )
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
thanks for the suggestions!
i will try and get back
User | Count |
---|---|
131 | |
71 | |
70 | |
58 | |
54 |
User | Count |
---|---|
194 | |
95 | |
65 | |
62 | |
53 |